mirror of
https://github.com/postgres/postgres.git
synced 2025-05-11 05:41:32 +03:00
There are other operators that have limited number data type support, so just remove the sentence. Reported-by: Sergei Agalakov Discussion: https://postgr.es/m/158032651854.19851.16261832706661813796@wrigleys.postgresql.org Backpatch-through: 9.5
22696 lines
821 KiB
Plaintext
22696 lines
821 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</literal></member>
|
|
<member><literal>OR</literal></member>
|
|
<member><literal>NOT</literal></member>
|
|
</simplelist>
|
|
|
|
<acronym>SQL</acronym> uses a three-valued logic system with true,
|
|
false, and <literal>null</literal>, which 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 Functions and Operators</title>
|
|
|
|
<indexterm zone="functions-comparison">
|
|
<primary>comparison</primary>
|
|
<secondary>operators</secondary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
The usual comparison operators are available, as shown in <xref
|
|
linkend="functions-comparison-op-table"/>.
|
|
</para>
|
|
|
|
<table id="functions-comparison-op-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>
|
|
There are also some comparison predicates, as shown in <xref
|
|
linkend="functions-comparison-pred-table"/>. These behave much like
|
|
operators, but have special syntax mandated by the SQL standard.
|
|
</para>
|
|
|
|
<table id="functions-comparison-pred-table">
|
|
<title>Comparison Predicates</title>
|
|
<tgroup cols="2">
|
|
<thead>
|
|
<row>
|
|
<entry>Predicate</entry>
|
|
<entry>Description</entry>
|
|
</row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
<row>
|
|
<entry> <replaceable>a</replaceable> <literal>BETWEEN</literal> <replaceable>x</replaceable> <literal>AND</literal> <replaceable>y</replaceable> </entry>
|
|
<entry>between</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <replaceable>a</replaceable> <literal>NOT BETWEEN</literal> <replaceable>x</replaceable> <literal>AND</literal> <replaceable>y</replaceable> </entry>
|
|
<entry>not between</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <replaceable>a</replaceable> <literal>BETWEEN SYMMETRIC</literal> <replaceable>x</replaceable> <literal>AND</literal> <replaceable>y</replaceable> </entry>
|
|
<entry>between, after sorting the comparison values</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <replaceable>a</replaceable> <literal>NOT BETWEEN SYMMETRIC</literal> <replaceable>x</replaceable> <literal>AND</literal> <replaceable>y</replaceable> </entry>
|
|
<entry>not between, after sorting the comparison values</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <replaceable>a</replaceable> <literal>IS DISTINCT FROM</literal> <replaceable>b</replaceable> </entry>
|
|
<entry>not equal, treating null like an ordinary value</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><replaceable>a</replaceable> <literal>IS NOT DISTINCT FROM</literal> <replaceable>b</replaceable></entry>
|
|
<entry>equal, treating null like an ordinary value</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <replaceable>expression</replaceable> <literal>IS NULL</literal> </entry>
|
|
<entry>is null</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <replaceable>expression</replaceable> <literal>IS NOT NULL</literal> </entry>
|
|
<entry>is not null</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <replaceable>expression</replaceable> <literal>ISNULL</literal> </entry>
|
|
<entry>is null (nonstandard syntax)</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <replaceable>expression</replaceable> <literal>NOTNULL</literal> </entry>
|
|
<entry>is not null (nonstandard syntax)</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <replaceable>boolean_expression</replaceable> <literal>IS TRUE</literal> </entry>
|
|
<entry>is true</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <replaceable>boolean_expression</replaceable> <literal>IS NOT TRUE</literal> </entry>
|
|
<entry>is false or unknown</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <replaceable>boolean_expression</replaceable> <literal>IS FALSE</literal> </entry>
|
|
<entry>is false</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <replaceable>boolean_expression</replaceable> <literal>IS NOT FALSE</literal> </entry>
|
|
<entry>is true or unknown</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <replaceable>boolean_expression</replaceable> <literal>IS UNKNOWN</literal> </entry>
|
|
<entry>is unknown</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <replaceable>boolean_expression</replaceable> <literal>IS NOT UNKNOWN</literal> </entry>
|
|
<entry>is true or false</entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
<indexterm>
|
|
<primary>BETWEEN</primary>
|
|
</indexterm>
|
|
The <token>BETWEEN</token> predicate simplifies range tests:
|
|
<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</literal> is like <literal>BETWEEN</literal>
|
|
except there is no requirement that the argument to the left of
|
|
<literal>AND</literal> 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 DISTINCT FROM</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>IS NOT DISTINCT FROM</primary>
|
|
</indexterm>
|
|
Ordinary comparison operators yield null (signifying <quote>unknown</quote>),
|
|
not true or false, when either input is null. For example,
|
|
<literal>7 = NULL</literal> yields null, as does <literal>7 <> NULL</literal>. When
|
|
this behavior is not suitable, use the
|
|
<literal>IS <optional> NOT </optional> DISTINCT FROM</literal> predicates:
|
|
<synopsis>
|
|
<replaceable>a</replaceable> IS DISTINCT FROM <replaceable>b</replaceable>
|
|
<replaceable>a</replaceable> IS NOT DISTINCT FROM <replaceable>b</replaceable>
|
|
</synopsis>
|
|
For non-null inputs, <literal>IS DISTINCT FROM</literal> is
|
|
the same as the <literal><></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 predicates effectively act as though null
|
|
were a normal data value, rather than <quote>unknown</quote>.
|
|
</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 predicates:
|
|
<synopsis>
|
|
<replaceable>expression</replaceable> IS NULL
|
|
<replaceable>expression</replaceable> IS NOT NULL
|
|
</synopsis>
|
|
or the equivalent, but nonstandard, predicates:
|
|
<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</literal> is not <quote>equal to</quote>
|
|
<literal>NULL</literal>. (The null value represents an unknown value,
|
|
and it is not known whether two unknown values are equal.)
|
|
</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>
|
|
|
|
<para>
|
|
If the <replaceable>expression</replaceable> is row-valued, then
|
|
<literal>IS NULL</literal> is true when the row expression itself is null
|
|
or when all the row's fields are null, while
|
|
<literal>IS NOT NULL</literal> 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</literal> and <literal>IS NOT NULL</literal> do not always return
|
|
inverse results for row-valued expressions; in particular, a row-valued
|
|
expression that contains both null and non-null fields will return false
|
|
for both tests. In some cases, it may be preferable to
|
|
write <replaceable>row</replaceable> <literal>IS DISTINCT FROM NULL</literal>
|
|
or <replaceable>row</replaceable> <literal>IS NOT DISTINCT FROM NULL</literal>,
|
|
which will simply check whether the overall row value is null without any
|
|
additional tests on the row fields.
|
|
</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 predicates
|
|
<synopsis>
|
|
<replaceable>boolean_expression</replaceable> IS TRUE
|
|
<replaceable>boolean_expression</replaceable> IS NOT TRUE
|
|
<replaceable>boolean_expression</replaceable> IS FALSE
|
|
<replaceable>boolean_expression</replaceable> IS NOT FALSE
|
|
<replaceable>boolean_expression</replaceable> IS UNKNOWN
|
|
<replaceable>boolean_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</quote>.
|
|
Notice that <literal>IS UNKNOWN</literal> and <literal>IS NOT UNKNOWN</literal> 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
|
|
predicates
|
|
<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>
|
|
-->
|
|
|
|
<para>
|
|
Some comparison-related functions are also available, as shown in <xref
|
|
linkend="functions-comparison-func-table"/>.
|
|
</para>
|
|
|
|
<table id="functions-comparison-func-table">
|
|
<title>Comparison 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>num_nonnulls</primary>
|
|
</indexterm>
|
|
<literal>num_nonnulls(VARIADIC "any")</literal>
|
|
</entry>
|
|
<entry>returns the number of non-null arguments</entry>
|
|
<entry><literal>num_nonnulls(1, NULL, 2)</literal></entry>
|
|
<entry><literal>2</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>num_nulls</primary>
|
|
</indexterm>
|
|
<literal>num_nulls(VARIADIC "any")</literal>
|
|
</entry>
|
|
<entry>returns the number of null arguments</entry>
|
|
<entry><literal>num_nulls(1, NULL, 2)</literal></entry>
|
|
<entry><literal>1</literal></entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
</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 (associates left to right)</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, and 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>nearest integer greater than or equal to 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>nearest integer greater than or equal to argument (same as <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</type>,
|
|
<parameter>x</parameter> <type>numeric</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>numeric</type></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>nearest integer less than or equal to 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>
|
|
<indexterm>
|
|
<primary>log10</primary>
|
|
</indexterm>
|
|
<literal><function>log10(<type>dp</type> or <type>numeric</type>)</function></literal>
|
|
</entry>
|
|
<entry>(same as input)</entry>
|
|
<entry>base 10 logarithm</entry>
|
|
<entry><literal>log10(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</parameter> 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</parameter> 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>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>scale</primary>
|
|
</indexterm>
|
|
<literal><function>scale(<type>numeric</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>integer</type></entry>
|
|
<entry>scale of the argument (the number of decimal digits in the fractional part)</entry>
|
|
<entry><literal>scale(8.41)</literal></entry>
|
|
<entry><literal>2</literal></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>operand</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 number to which <parameter>operand</parameter> would
|
|
be assigned in a histogram having <parameter>count</parameter> equal-width
|
|
buckets spanning the range <parameter>b1</parameter> to <parameter>b2</parameter>;
|
|
returns <literal>0</literal> or <literal><parameter>count</parameter>+1</literal> for
|
|
an input outside the range</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>operand</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 number to which <parameter>operand</parameter> would
|
|
be assigned in a histogram having <parameter>count</parameter> equal-width
|
|
buckets spanning the range <parameter>b1</parameter> to <parameter>b2</parameter>;
|
|
returns <literal>0</literal> or <literal><parameter>count</parameter>+1</literal> for
|
|
an input outside the range</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>operand</parameter> <type>anyelement</type>, <parameter>thresholds</parameter> <type>anyarray</type>)</function></literal></entry>
|
|
<entry><type>int</type></entry>
|
|
<entry>return the bucket number to which <parameter>operand</parameter> would
|
|
be assigned given an array listing the lower bounds of the buckets;
|
|
returns <literal>0</literal> for an input less than the first lower bound;
|
|
the <parameter>thresholds</parameter> array <emphasis>must be sorted</emphasis>,
|
|
smallest first, or unexpected results will be obtained</entry>
|
|
<entry><literal>width_bucket(now(), array['yesterday', 'today', 'tomorrow']::timestamptz[])</literal></entry>
|
|
<entry><literal>2</literal></entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
<xref linkend="functions-math-random-table"/> shows functions for
|
|
generating random numbers.
|
|
</para>
|
|
|
|
<table id="functions-math-random-table">
|
|
<title>Random Functions</title>
|
|
|
|
<tgroup cols="3">
|
|
<thead>
|
|
<row>
|
|
<entry>Function</entry>
|
|
<entry>Return Type</entry>
|
|
<entry>Description</entry>
|
|
</row>
|
|
</thead>
|
|
<tbody>
|
|
<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>
|
|
</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>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
The <function>random()</function> function uses a simple linear
|
|
congruential algorithm. It is fast but not suitable for cryptographic
|
|
applications; see the <xref linkend="pgcrypto"/> module for a more
|
|
secure alternative.
|
|
If <function>setseed()</function> is called, the results of
|
|
subsequent <function>random()</function> calls in the current session are
|
|
repeatable by re-issuing <function>setseed()</function> with the same
|
|
argument.
|
|
</para>
|
|
|
|
<para>
|
|
<xref linkend="functions-math-trig-table"/> shows the
|
|
available trigonometric functions. All these functions
|
|
take arguments and return values of type <type>double
|
|
precision</type>. Each of the trigonometric functions comes in
|
|
two variants, one that measures angles in radians and one that
|
|
measures angles in degrees.
|
|
</para>
|
|
|
|
<table id="functions-math-trig-table">
|
|
<title>Trigonometric Functions</title>
|
|
|
|
<tgroup cols="3">
|
|
<thead>
|
|
<row>
|
|
<entry>Function (radians)</entry>
|
|
<entry>Function (degrees)</entry>
|
|
<entry>Description</entry>
|
|
</row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>acos</primary>
|
|
</indexterm><literal><function>acos(<replaceable>x</replaceable>)</function></literal>
|
|
</entry>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>acosd</primary>
|
|
</indexterm><literal><function>acosd(<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>
|
|
<indexterm>
|
|
<primary>asind</primary>
|
|
</indexterm>
|
|
<literal><function>asind(<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>
|
|
<indexterm>
|
|
<primary>atand</primary>
|
|
</indexterm>
|
|
<literal><function>atand(<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>
|
|
<indexterm>
|
|
<primary>atan2d</primary>
|
|
</indexterm>
|
|
<literal><function>atan2d(<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>
|
|
<indexterm>
|
|
<primary>cosd</primary>
|
|
</indexterm>
|
|
<literal><function>cosd(<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>
|
|
<indexterm>
|
|
<primary>cotd</primary>
|
|
</indexterm>
|
|
<literal><function>cotd(<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>
|
|
<indexterm>
|
|
<primary>sind</primary>
|
|
</indexterm>
|
|
<literal><function>sind(<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>
|
|
<indexterm>
|
|
<primary>tand</primary>
|
|
</indexterm>
|
|
<literal><function>tand(<replaceable>x</replaceable>)</function></literal>
|
|
</entry>
|
|
<entry>tangent</entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<note>
|
|
<para>
|
|
Another way to work with angles measured in degrees is to use the unit
|
|
transformation functions <literal><function>radians()</function></literal>
|
|
and <literal><function>degrees()</function></literal> shown earlier.
|
|
However, using the degree-based trigonometric functions is preferred,
|
|
as that way avoids round-off error for special cases such
|
|
as <literal>sind(30)</literal>.
|
|
</para>
|
|
</note>
|
|
|
|
<para>
|
|
<xref linkend="functions-math-hyp-table"/> shows the
|
|
available hyperbolic functions. All these functions
|
|
take arguments and return values of type <type>double
|
|
precision</type>.
|
|
</para>
|
|
|
|
<table id="functions-math-hyp-table">
|
|
<title>Hyperbolic Functions</title>
|
|
|
|
<tgroup cols="4">
|
|
<thead>
|
|
<row>
|
|
<entry>Function</entry>
|
|
<entry>Description</entry>
|
|
<entry>Example</entry>
|
|
<entry>Result</entry>
|
|
</row>
|
|
</thead>
|
|
<tbody>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>sinh</primary>
|
|
</indexterm>
|
|
<literal><function>sinh(<replaceable>x</replaceable>)</function></literal>
|
|
</entry>
|
|
<entry>hyperbolic sine</entry>
|
|
<entry><literal>sinh(0)</literal></entry>
|
|
<entry><literal>0</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>cosh</primary>
|
|
</indexterm>
|
|
<literal><function>cosh(<replaceable>x</replaceable>)</function></literal>
|
|
</entry>
|
|
<entry>hyperbolic cosine</entry>
|
|
<entry><literal>cosh(0)</literal></entry>
|
|
<entry><literal>1</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>tanh</primary>
|
|
</indexterm>
|
|
<literal><function>tanh(<replaceable>x</replaceable>)</function></literal>
|
|
</entry>
|
|
<entry>hyperbolic tangent</entry>
|
|
<entry><literal>tanh(0)</literal></entry>
|
|
<entry><literal>0</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>asinh</primary>
|
|
</indexterm>
|
|
<literal><function>asinh(<replaceable>x</replaceable>)</function></literal>
|
|
</entry>
|
|
<entry>inverse hyperbolic sine</entry>
|
|
<entry><literal>asinh(0)</literal></entry>
|
|
<entry><literal>0</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>acosh</primary>
|
|
</indexterm>
|
|
<literal><function>acosh(<replaceable>x</replaceable>)</function></literal>
|
|
</entry>
|
|
<entry>inverse hyperbolic cosine</entry>
|
|
<entry><literal>acosh(1)</literal></entry>
|
|
<entry><literal>0</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>atanh</primary>
|
|
</indexterm>
|
|
<literal><function>atanh(<replaceable>x</replaceable>)</function></literal>
|
|
</entry>
|
|
<entry>inverse hyperbolic tangent</entry>
|
|
<entry><literal>atanh(0)</literal></entry>
|
|
<entry><literal>0</literal></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</productname> 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</type>. Those coercions have been removed because they frequently
|
|
caused surprising behaviors. However, the string concatenation operator
|
|
(<literal>||</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</type> 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 characters from
|
|
<parameter>characters</parameter> (a space by default) from the
|
|
start, end, or both ends (<literal>both</literal> is the default)
|
|
of <parameter>string</parameter>
|
|
</entry>
|
|
<entry><literal>trim(both 'xyz' from 'yxTomxx')</literal></entry>
|
|
<entry><literal>Tom</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<literal><function>trim(<optional>leading | trailing
|
|
| both</optional> <optional>from</optional>
|
|
<parameter>string</parameter>
|
|
<optional>, <parameter>characters</parameter></optional>
|
|
)</function></literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>
|
|
Non-standard syntax for <function>trim()</function>
|
|
</entry>
|
|
<entry><literal>trim(both from 'yxTomxx', 'xyz')</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', 'xyz')</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 the text representations of all the 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 the first argument with separators. The first
|
|
argument is used as the separator string. 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>format</parameter> <type>text</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>bytea</type></entry>
|
|
<entry>
|
|
Decode binary data from textual representation in <parameter>string</parameter>.
|
|
Options for <parameter>format</parameter> are same as in <function>encode</function>.
|
|
</entry>
|
|
<entry><literal>decode('MTIzAAE=', 'base64')</literal></entry>
|
|
<entry><literal>\x3132330001</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>encode</primary>
|
|
</indexterm>
|
|
<literal><function>encode(<parameter>data</parameter> <type>bytea</type>,
|
|
<parameter>format</parameter> <type>text</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>
|
|
Encode binary data into a textual representation. Supported
|
|
formats are: <literal>base64</literal>, <literal>hex</literal>, <literal>escape</literal>.
|
|
<literal>escape</literal> converts zero bytes and high-bit-set bytes to
|
|
octal sequences (<literal>\</literal><replaceable>nnn</replaceable>) and
|
|
doubles backslashes.
|
|
</entry>
|
|
<entry><literal>encode('123\000\001', 'base64')</literal></entry>
|
|
<entry><literal>MTIzAAE=</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry id="format">
|
|
<indexterm>
|
|
<primary>format</primary>
|
|
</indexterm>
|
|
<literal><function>format</function>(<parameter>formatstr</parameter> <type>text</type>
|
|
[, <parameter>formatarg</parameter> <type>"any"</type> [, ...] ])</literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>
|
|
Format arguments according to a format string.
|
|
This function is similar to the C function <function>sprintf</function>.
|
|
See <xref linkend="functions-string-format"/>.
|
|
</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</replaceable> characters in the string. When <replaceable>n</replaceable>
|
|
is negative, return all but last |<replaceable>n</replaceable>| 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('zzzytest', 'xyz')</literal></entry>
|
|
<entry><literal>test</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>parse_ident</primary>
|
|
</indexterm>
|
|
<literal><function>parse_ident(<parameter>qualified_identifier</parameter> <type>text</type>
|
|
[, <parameter>strictmode</parameter> <type>boolean</type> DEFAULT true ] )</function></literal>
|
|
</entry>
|
|
<entry><type>text[]</type></entry>
|
|
<entry>
|
|
Split <parameter>qualified_identifier</parameter> into an array of
|
|
identifiers, removing any quoting of individual identifiers. By
|
|
default, extra characters after the last identifier are considered an
|
|
error; but if the second parameter is <literal>false</literal>, then such
|
|
extra characters are ignored. (This behavior is useful for parsing
|
|
names for objects like functions.) Note that this function does not
|
|
truncate over-length identifiers. If you want truncation you can cast
|
|
the result to <type>name[]</type>.
|
|
</entry>
|
|
<entry><literal>parse_ident('"SomeSchema".someTable')</literal></entry>
|
|
<entry><literal>{SomeSchema,sometable}</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(E'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</literal>.
|
|
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</literal>.
|
|
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_match</primary>
|
|
</indexterm>
|
|
<literal><function>regexp_match(<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>
|
|
Return captured substring(s) resulting from the first match of a POSIX
|
|
regular expression to the <parameter>string</parameter>. See
|
|
<xref linkend="functions-posix-regexp"/> for more information.
|
|
</entry>
|
|
<entry><literal>regexp_match('foobarbequebaz', '(bar)(beque)')</literal></entry>
|
|
<entry><literal>{bar,beque}</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 captured substring(s) resulting from matching a POSIX regular
|
|
expression to the <parameter>string</parameter>. See
|
|
<xref linkend="functions-posix-regexp"/> for more information.
|
|
</entry>
|
|
<entry><literal>regexp_matches('foobarbequebaz', 'ba.', 'g')</literal></entry>
|
|
<entry><literal>{bar}</literal><para><literal>{baz}</literal></para> (2 rows)</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', '\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', '\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</replaceable> characters in the string. When <replaceable>n</replaceable>
|
|
is negative, return all but first |<replaceable>n</replaceable>| 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('testxxzx', 'xyz')</literal></entry>
|
|
<entry><literal>test</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>starts_with</primary>
|
|
</indexterm>
|
|
<literal><function>starts_with(<parameter>string</parameter>, <parameter>prefix</parameter>)</function></literal>
|
|
</entry>
|
|
<entry><type>bool</type></entry>
|
|
<entry>
|
|
Returns true if <parameter>string</parameter> starts with <parameter>prefix</parameter>.
|
|
</entry>
|
|
<entry><literal>starts_with('alphabet', 'alph')</literal></entry>
|
|
<entry><literal>t</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>, <literal>LATIN2</literal>, <literal>LATIN9</literal>,
|
|
and <literal>WIN1250</literal> 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>
|
|
The <function>concat</function>, <function>concat_ws</function> and
|
|
<function>format</function> functions are variadic, so it is possible to
|
|
pass the values to be concatenated or formatted as an array marked with
|
|
the <literal>VARIADIC</literal> keyword (see <xref
|
|
linkend="xfunc-sql-variadic-functions"/>). The array's elements are
|
|
treated as if they were separate ordinary arguments to the function.
|
|
If the variadic array argument is NULL, <function>concat</function>
|
|
and <function>concat_ws</function> return NULL, but
|
|
<function>format</function> treats a NULL as a zero-element array.
|
|
</para>
|
|
|
|
<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>windows_1258_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_windows_1258</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>utf8_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>utf8_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>
|
|
|
|
<sect2 id="functions-string-format">
|
|
<title><function>format</function></title>
|
|
|
|
<indexterm>
|
|
<primary>format</primary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
The function <function>format</function> produces output formatted according to
|
|
a format string, in a style similar to the C function
|
|
<function>sprintf</function>.
|
|
</para>
|
|
|
|
<para>
|
|
<synopsis>
|
|
<function>format</function>(<parameter>formatstr</parameter> <type>text</type> [, <parameter>formatarg</parameter> <type>"any"</type> [, ...] ])
|
|
</synopsis>
|
|
<replaceable>formatstr</replaceable> is a format string that specifies how the
|
|
result should be formatted. Text in the format string is copied
|
|
directly to the result, except where <firstterm>format specifiers</firstterm> are
|
|
used. Format specifiers act as placeholders in the string, defining how
|
|
subsequent function arguments should be formatted and inserted into the
|
|
result. Each <replaceable>formatarg</replaceable> argument is converted to text
|
|
according to the usual output rules for its data type, and then formatted
|
|
and inserted into the result string according to the format specifier(s).
|
|
</para>
|
|
|
|
<para>
|
|
Format specifiers are introduced by a <literal>%</literal> character and have
|
|
the form
|
|
<synopsis>
|
|
%[<replaceable>position</replaceable>][<replaceable>flags</replaceable>][<replaceable>width</replaceable>]<replaceable>type</replaceable>
|
|
</synopsis>
|
|
where the component fields are:
|
|
|
|
<variablelist>
|
|
<varlistentry>
|
|
<term><replaceable>position</replaceable> (optional)</term>
|
|
<listitem>
|
|
<para>
|
|
A string of the form <literal><replaceable>n</replaceable>$</literal> where
|
|
<replaceable>n</replaceable> is the index of the argument to print.
|
|
Index 1 means the first argument after
|
|
<replaceable>formatstr</replaceable>. If the <replaceable>position</replaceable> is
|
|
omitted, the default is to use the next argument in sequence.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><replaceable>flags</replaceable> (optional)</term>
|
|
<listitem>
|
|
<para>
|
|
Additional options controlling how the format specifier's output is
|
|
formatted. Currently the only supported flag is a minus sign
|
|
(<literal>-</literal>) which will cause the format specifier's output to be
|
|
left-justified. This has no effect unless the <replaceable>width</replaceable>
|
|
field is also specified.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><replaceable>width</replaceable> (optional)</term>
|
|
<listitem>
|
|
<para>
|
|
Specifies the <emphasis>minimum</emphasis> number of characters to use to
|
|
display the format specifier's output. The output is padded on the
|
|
left or right (depending on the <literal>-</literal> flag) with spaces as
|
|
needed to fill the width. A too-small width does not cause
|
|
truncation of the output, but is simply ignored. The width may be
|
|
specified using any of the following: a positive integer; an
|
|
asterisk (<literal>*</literal>) to use the next function argument as the
|
|
width; or a string of the form <literal>*<replaceable>n</replaceable>$</literal> to
|
|
use the <replaceable>n</replaceable>th function argument as the width.
|
|
</para>
|
|
|
|
<para>
|
|
If the width comes from a function argument, that argument is
|
|
consumed before the argument that is used for the format specifier's
|
|
value. If the width argument is negative, the result is left
|
|
aligned (as if the <literal>-</literal> flag had been specified) within a
|
|
field of length <function>abs</function>(<replaceable>width</replaceable>).
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><replaceable>type</replaceable> (required)</term>
|
|
<listitem>
|
|
<para>
|
|
The type of format conversion to use to produce the format
|
|
specifier's output. The following types are supported:
|
|
<itemizedlist>
|
|
<listitem>
|
|
<para>
|
|
<literal>s</literal> formats the argument value as a simple
|
|
string. A null value is treated as an empty string.
|
|
</para>
|
|
</listitem>
|
|
<listitem>
|
|
<para>
|
|
<literal>I</literal> treats the argument value as an SQL
|
|
identifier, double-quoting it if necessary.
|
|
It is an error for the value to be null (equivalent to
|
|
<function>quote_ident</function>).
|
|
</para>
|
|
</listitem>
|
|
<listitem>
|
|
<para>
|
|
<literal>L</literal> quotes the argument value as an SQL literal.
|
|
A null value is displayed as the string <literal>NULL</literal>, without
|
|
quotes (equivalent to <function>quote_nullable</function>).
|
|
</para>
|
|
</listitem>
|
|
</itemizedlist>
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
</variablelist>
|
|
</para>
|
|
|
|
<para>
|
|
In addition to the format specifiers described above, the special sequence
|
|
<literal>%%</literal> may be used to output a literal <literal>%</literal> character.
|
|
</para>
|
|
|
|
<para>
|
|
Here are some examples of the basic format conversions:
|
|
|
|
<screen>
|
|
SELECT format('Hello %s', 'World');
|
|
<lineannotation>Result: </lineannotation><computeroutput>Hello World</computeroutput>
|
|
|
|
SELECT format('Testing %s, %s, %s, %%', 'one', 'two', 'three');
|
|
<lineannotation>Result: </lineannotation><computeroutput>Testing one, two, three, %</computeroutput>
|
|
|
|
SELECT format('INSERT INTO %I VALUES(%L)', 'Foo bar', E'O\'Reilly');
|
|
<lineannotation>Result: </lineannotation><computeroutput>INSERT INTO "Foo bar" VALUES('O''Reilly')</computeroutput>
|
|
|
|
SELECT format('INSERT INTO %I VALUES(%L)', 'locations', 'C:\Program Files');
|
|
<lineannotation>Result: </lineannotation><computeroutput>INSERT INTO locations VALUES('C:\Program Files')</computeroutput>
|
|
</screen>
|
|
</para>
|
|
|
|
<para>
|
|
Here are examples using <replaceable>width</replaceable> fields
|
|
and the <literal>-</literal> flag:
|
|
|
|
<screen>
|
|
SELECT format('|%10s|', 'foo');
|
|
<lineannotation>Result: </lineannotation><computeroutput>| foo|</computeroutput>
|
|
|
|
SELECT format('|%-10s|', 'foo');
|
|
<lineannotation>Result: </lineannotation><computeroutput>|foo |</computeroutput>
|
|
|
|
SELECT format('|%*s|', 10, 'foo');
|
|
<lineannotation>Result: </lineannotation><computeroutput>| foo|</computeroutput>
|
|
|
|
SELECT format('|%*s|', -10, 'foo');
|
|
<lineannotation>Result: </lineannotation><computeroutput>|foo |</computeroutput>
|
|
|
|
SELECT format('|%-*s|', 10, 'foo');
|
|
<lineannotation>Result: </lineannotation><computeroutput>|foo |</computeroutput>
|
|
|
|
SELECT format('|%-*s|', -10, 'foo');
|
|
<lineannotation>Result: </lineannotation><computeroutput>|foo |</computeroutput>
|
|
</screen>
|
|
</para>
|
|
|
|
<para>
|
|
These examples show use of <replaceable>position</replaceable> fields:
|
|
|
|
<screen>
|
|
SELECT format('Testing %3$s, %2$s, %1$s', 'one', 'two', 'three');
|
|
<lineannotation>Result: </lineannotation><computeroutput>Testing three, two, one</computeroutput>
|
|
|
|
SELECT format('|%*2$s|', 'foo', 10, 'bar');
|
|
<lineannotation>Result: </lineannotation><computeroutput>| bar|</computeroutput>
|
|
|
|
SELECT format('|%1$*2$s|', 'foo', 10, 'bar');
|
|
<lineannotation>Result: </lineannotation><computeroutput>| foo|</computeroutput>
|
|
</screen>
|
|
</para>
|
|
|
|
<para>
|
|
Unlike the standard C function <function>sprintf</function>,
|
|
<productname>PostgreSQL</productname>'s <function>format</function> function allows format
|
|
specifiers with and without <replaceable>position</replaceable> fields to be mixed
|
|
in the same format string. A format specifier without a
|
|
<replaceable>position</replaceable> field always uses the next argument after the
|
|
last argument consumed.
|
|
In addition, the <function>format</function> function does not require all
|
|
function arguments to be used in the format string.
|
|
For example:
|
|
|
|
<screen>
|
|
SELECT format('Testing %3$s, %2$s, %s', 'one', 'two', 'three');
|
|
<lineannotation>Result: </lineannotation><computeroutput>Testing three, two, three</computeroutput>
|
|
</screen>
|
|
</para>
|
|
|
|
<para>
|
|
The <literal>%I</literal> and <literal>%L</literal> format specifiers are particularly
|
|
useful for safely constructing dynamic SQL statements. See
|
|
<xref linkend="plpgsql-quote-literal-example"/>.
|
|
</para>
|
|
</sect2>
|
|
|
|
</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</productname> also provides versions of these functions
|
|
that use the regular function invocation syntax
|
|
(see <xref linkend="functions-binarystring-other"/>).
|
|
</para>
|
|
|
|
<note>
|
|
<para>
|
|
The sample results shown on this page assume that the server parameter
|
|
<link linkend="guc-bytea-output"><varname>bytea_output</varname></link> is set
|
|
to <literal>escape</literal> (the traditional PostgreSQL format).
|
|
</para>
|
|
</note>
|
|
|
|
<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>'\\Post'::bytea || '\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('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('Th\000omas'::bytea placing '\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('\000om'::bytea in '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('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 bytes appearing in
|
|
<parameter>bytes</parameter> from the start
|
|
and end of <parameter>string</parameter>
|
|
</entry>
|
|
<entry><literal>trim('\000\001'::bytea from '\000Tom\001'::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 containing only bytes appearing in
|
|
<parameter>bytes</parameter> from the start and end of
|
|
<parameter>string</parameter>
|
|
</entry>
|
|
<entry><literal>btrim('\000trim\001'::bytea, '\000\001'::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>format</parameter> <type>text</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>bytea</type></entry>
|
|
<entry>
|
|
Decode binary data from textual representation in <parameter>string</parameter>.
|
|
Options for <parameter>format</parameter> are same as in <function>encode</function>.
|
|
</entry>
|
|
<entry><literal>decode('123\000456', 'escape')</literal></entry>
|
|
<entry><literal>123\000456</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>encode</primary>
|
|
</indexterm>
|
|
<literal><function>encode(<parameter>data</parameter> <type>bytea</type>,
|
|
<parameter>format</parameter> <type>text</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>
|
|
Encode binary data into a textual representation. Supported
|
|
formats are: <literal>base64</literal>, <literal>hex</literal>, <literal>escape</literal>.
|
|
<literal>escape</literal> converts zero bytes and high-bit-set bytes to
|
|
octal sequences (<literal>\</literal><replaceable>nnn</replaceable>) and
|
|
doubles backslashes.
|
|
</entry>
|
|
<entry><literal>encode('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('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('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('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('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</parameter>)</function></literal>
|
|
</entry>
|
|
<entry><type>bytea</type></entry>
|
|
<entry>
|
|
Set bit in string
|
|
</entry>
|
|
<entry><literal>set_bit('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</parameter>)</function></literal>
|
|
</entry>
|
|
<entry><type>bytea</type></entry>
|
|
<entry>
|
|
Set byte in string
|
|
</entry>
|
|
<entry><literal>set_byte('Th\000omas'::bytea, 4, 64)</literal></entry>
|
|
<entry><literal>Th\000o@as</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>sha224</primary>
|
|
</indexterm>
|
|
<literal><function>sha224(<type>bytea</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>bytea</type></entry>
|
|
<entry>
|
|
SHA-224 hash
|
|
</entry>
|
|
<entry><literal>sha224('abc')</literal></entry>
|
|
<entry><literal>\x23097d223405d8228642a477bda2​55b32aadbce4bda0b3f7e36c9da7</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>sha256</primary>
|
|
</indexterm>
|
|
<literal><function>sha256(<type>bytea</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>bytea</type></entry>
|
|
<entry>
|
|
SHA-256 hash
|
|
</entry>
|
|
<entry><literal>sha256('abc')</literal></entry>
|
|
<entry><literal>\xba7816bf8f01cfea414140de5dae2223​b00361a396177a9cb410ff61f20015ad</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>sha384</primary>
|
|
</indexterm>
|
|
<literal><function>sha384(<type>bytea</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>bytea</type></entry>
|
|
<entry>
|
|
SHA-384 hash
|
|
</entry>
|
|
<entry><literal>sha384('abc')</literal></entry>
|
|
<entry><literal>\xcb00753f45a35e8bb5a03d699ac65007​272c32ab0eded1631a8b605a43ff5bed​8086072ba1e7cc2358baeca134c825a7</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>sha512</primary>
|
|
</indexterm>
|
|
<literal><function>sha512(<type>bytea</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>bytea</type></entry>
|
|
<entry>
|
|
SHA-512 hash
|
|
</entry>
|
|
<entry><literal>sha512('abc')</literal></entry>
|
|
<entry><literal>\xddaf35a193617abacc417349ae204131​12e6fa4e89a97ea20a9eeee64b55d39a​2192992a274fc1a836ba3c23a3feebbd​454d4423643ce80e2a9ac94fa54ca49f</literal></entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
<function>get_byte</function> and <function>set_byte</function> number the first byte
|
|
of a binary string as byte 0.
|
|
<function>get_bit</function> and <function>set_bit</function> 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>
|
|
|
|
<para>
|
|
Note that for historic reasons, the function <function>md5</function>
|
|
returns a hex-encoded value of type <type>text</type> whereas the SHA-2
|
|
functions return type <type>bytea</type>. Use the functions
|
|
<function>encode</function> and <function>decode</function> to convert
|
|
between the two, for example <literal>encode(sha256('abc'),
|
|
'hex')</literal> to get a hex-encoded text representation.
|
|
</para>
|
|
|
|
<para>
|
|
See also the aggregate function <function>string_agg</function> in
|
|
<xref linkend="functions-aggregate"/> and the large object functions
|
|
in <xref linkend="lo-funcs"/>.
|
|
</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</type>.
|
|
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</quote> means casting to
|
|
<literal>bit(1)</literal>, and so will deliver only the least significant
|
|
bit of the integer.
|
|
</para>
|
|
|
|
<note>
|
|
<para>
|
|
Casting an integer to <type>bit(n)</type> copies the rightmost
|
|
<literal>n</literal> bits. 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?</quote> 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>
|
|
|
|
<caution>
|
|
<para>
|
|
While most regular-expression searches can be executed very quickly,
|
|
regular expressions can be contrived that take arbitrary amounts of
|
|
time and memory to process. Be wary of accepting regular-expression
|
|
search patterns from hostile sources. If you must do so, it is
|
|
advisable to impose a statement timeout.
|
|
</para>
|
|
|
|
<para>
|
|
Searches using <function>SIMILAR TO</function> patterns have the same
|
|
security hazards, since <function>SIMILAR TO</function> provides many
|
|
of the same capabilities as <acronym>POSIX</acronym>-style regular
|
|
expressions.
|
|
</para>
|
|
|
|
<para>
|
|
<function>LIKE</function> searches, being much simpler than the other
|
|
two options, are safer to use with possibly-hostile pattern sources.
|
|
</para>
|
|
</caution>
|
|
|
|
<para>
|
|
The pattern matching operators of all three kinds do not support
|
|
nondeterministic collations. If required, apply a different collation to
|
|
the expression to work around this limitation.
|
|
</para>
|
|
|
|
<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, if it's desired 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>
|
|
|
|
<note>
|
|
<para>
|
|
If you have <xref linkend="guc-standard-conforming-strings"/> turned off,
|
|
any backslashes you write in literal string constants will need to be
|
|
doubled. See <xref linkend="sql-syntax-strings"/> for more information.
|
|
</para>
|
|
</note>
|
|
|
|
<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. You may see these
|
|
operator names in <command>EXPLAIN</command> output and similar
|
|
places, since the parser actually translates <function>LIKE</function>
|
|
et al. to these operators.
|
|
</para>
|
|
|
|
<para>
|
|
The phrases <function>LIKE</function>, <function>ILIKE</function>,
|
|
<function>NOT LIKE</function>, and <function>NOT ILIKE</function> are
|
|
generally treated as operators
|
|
in <productname>PostgreSQL</productname> syntax; for example they can
|
|
be used in <replaceable>expression</replaceable>
|
|
<replaceable>operator</replaceable> ANY
|
|
(<replaceable>subquery</replaceable>) constructs, although
|
|
an <literal>ESCAPE</literal> clause cannot be included there. In some
|
|
obscure cases it may be necessary to use the underlying operator names
|
|
instead.
|
|
</para>
|
|
|
|
<para>
|
|
There is also the prefix operator <literal>^@</literal> and corresponding
|
|
<function>starts_with</function> function which covers cases when only
|
|
searching by beginning of the string is needed.
|
|
</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>_</literal> and <literal>%</literal> as wildcard characters denoting
|
|
any single character and any string, respectively (these are
|
|
comparable to <literal>.</literal> and <literal>.*</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>{</literal><replaceable>m</replaceable><literal>}</literal> denotes repetition
|
|
of the previous item exactly <replaceable>m</replaceable> times.
|
|
</para>
|
|
</listitem>
|
|
<listitem>
|
|
<para>
|
|
<literal>{</literal><replaceable>m</replaceable><literal>,}</literal> denotes repetition
|
|
of the previous item <replaceable>m</replaceable> or more times.
|
|
</para>
|
|
</listitem>
|
|
<listitem>
|
|
<para>
|
|
<literal>{</literal><replaceable>m</replaceable><literal>,</literal><replaceable>n</replaceable><literal>}</literal>
|
|
denotes repetition of the previous item at least <replaceable>m</replaceable> and
|
|
not more than <replaceable>n</replaceable> 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>.</literal>) is not a metacharacter
|
|
for <function>SIMILAR TO</function>.
|
|
</para>
|
|
|
|
<para>
|
|
As with <function>LIKE</function>, a backslash disables the special meaning
|
|
of any of these metacharacters; or a different escape character can
|
|
be specified with <literal>ESCAPE</literal>.
|
|
</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> function with three parameters
|
|
provides extraction of a substring that matches an SQL
|
|
regular expression pattern. The function can be written according
|
|
to SQL99 syntax:
|
|
<synopsis>
|
|
substring(<replaceable>string</replaceable> from <replaceable>pattern</replaceable> for <replaceable>escape-character</replaceable>)
|
|
</synopsis>
|
|
or as a plain three-argument function:
|
|
<synopsis>
|
|
substring(<replaceable>string</replaceable>, <replaceable>pattern</replaceable>, <replaceable>escape-character</replaceable>)
|
|
</synopsis>
|
|
As with <literal>SIMILAR TO</literal>, the
|
|
specified pattern must match the entire data string, or else the
|
|
function fails and returns null. To indicate the part of the
|
|
pattern for which the matching data sub-string is of interest,
|
|
the pattern should contain
|
|
two occurrences of the escape character followed by a double quote
|
|
(<literal>"</literal>). <!-- " font-lock sanity -->
|
|
The text matching the portion of the pattern
|
|
between these separators is returned when the match is successful.
|
|
</para>
|
|
|
|
<para>
|
|
The escape-double-quote separators actually
|
|
divide <function>substring</function>'s pattern into three independent
|
|
regular expressions; for example, a vertical bar (<literal>|</literal>)
|
|
in any of the three sections affects only that section. Also, the first
|
|
and third of these regular expressions are defined to match the smallest
|
|
possible amount of text, not the largest, when there is any ambiguity
|
|
about how much of the data string matches which pattern. (In POSIX
|
|
parlance, the first and third regular expressions are forced to be
|
|
non-greedy.)
|
|
</para>
|
|
|
|
<para>
|
|
As an extension to the SQL standard, <productname>PostgreSQL</productname>
|
|
allows there to be just one escape-double-quote separator, in which case
|
|
the third regular expression is taken as empty; or no separators, in which
|
|
case the first and third regular expressions are taken as empty.
|
|
</para>
|
|
|
|
<para>
|
|
Some examples, with <literal>#"</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_match</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</function> 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> 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> 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>,
|
|
<replaceable>pattern</replaceable>, <replaceable>replacement</replaceable>
|
|
<optional>, <replaceable>flags</replaceable> </optional>).
|
|
The <replaceable>source</replaceable> string is returned unchanged if
|
|
there is no match to the <replaceable>pattern</replaceable>. If there is a
|
|
match, the <replaceable>source</replaceable> string is returned with the
|
|
<replaceable>replacement</replaceable> string substituted for the matching
|
|
substring. The <replaceable>replacement</replaceable> string can contain
|
|
<literal>\</literal><replaceable>n</replaceable>, where <replaceable>n</replaceable> is 1
|
|
through 9, to indicate that the source substring matching the
|
|
<replaceable>n</replaceable>'th parenthesized subexpression of the pattern should be
|
|
inserted, and it can contain <literal>\&</literal> to indicate that the
|
|
substring matching the entire pattern should be inserted. Write
|
|
<literal>\\</literal> if you need to put a literal backslash in the replacement
|
|
text.
|
|
The <replaceable>flags</replaceable> parameter is an optional text
|
|
string containing zero or more single-letter flags that change the
|
|
function's behavior. Flag <literal>i</literal> specifies case-insensitive
|
|
matching, while flag <literal>g</literal> specifies replacement of each matching
|
|
substring rather than only the first one. Supported flags (though
|
|
not <literal>g</literal>) 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(..)', 'X\1Y', 'g')
|
|
<lineannotation>fooXarYXazY</lineannotation>
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
The <function>regexp_match</function> function returns a text array of
|
|
captured substring(s) resulting from the first match of a POSIX
|
|
regular expression pattern to a string. It has the syntax
|
|
<function>regexp_match</function>(<replaceable>string</replaceable>,
|
|
<replaceable>pattern</replaceable> <optional>, <replaceable>flags</replaceable> </optional>).
|
|
If there is no match, the result is <literal>NULL</literal>.
|
|
If a match is found, and the <replaceable>pattern</replaceable> contains no
|
|
parenthesized subexpressions, then the result is a single-element text
|
|
array containing the substring matching the whole pattern.
|
|
If a match is found, and the <replaceable>pattern</replaceable> contains
|
|
parenthesized subexpressions, then the result is a text array
|
|
whose <replaceable>n</replaceable>'th element is the substring matching
|
|
the <replaceable>n</replaceable>'th parenthesized subexpression of
|
|
the <replaceable>pattern</replaceable> (not counting <quote>non-capturing</quote>
|
|
parentheses; see below for details).
|
|
The <replaceable>flags</replaceable> parameter is an optional text string
|
|
containing zero or more single-letter flags that change the function's
|
|
behavior. Supported flags are described
|
|
in <xref linkend="posix-embedded-options-table"/>.
|
|
</para>
|
|
|
|
<para>
|
|
Some examples:
|
|
<programlisting>
|
|
SELECT regexp_match('foobarbequebaz', 'bar.*que');
|
|
regexp_match
|
|
--------------
|
|
{barbeque}
|
|
(1 row)
|
|
|
|
SELECT regexp_match('foobarbequebaz', '(bar)(beque)');
|
|
regexp_match
|
|
--------------
|
|
{bar,beque}
|
|
(1 row)
|
|
</programlisting>
|
|
In the common case where you just want the whole matching substring
|
|
or <literal>NULL</literal> for no match, write something like
|
|
<programlisting>
|
|
SELECT (regexp_match('foobarbequebaz', 'bar.*que'))[1];
|
|
regexp_match
|
|
--------------
|
|
barbeque
|
|
(1 row)
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
The <function>regexp_matches</function> function returns a set of text arrays
|
|
of captured substring(s) resulting from matching a POSIX regular
|
|
expression pattern to a string. It has the same syntax as
|
|
<function>regexp_match</function>.
|
|
This function returns no rows if there is no match, one row if there is
|
|
a match and the <literal>g</literal> flag is not given, or <replaceable>N</replaceable>
|
|
rows if there are <replaceable>N</replaceable> matches and the <literal>g</literal> flag
|
|
is given. Each returned row is a text array containing the whole
|
|
matched substring or the substrings matching parenthesized
|
|
subexpressions of the <replaceable>pattern</replaceable>, just as described above
|
|
for <function>regexp_match</function>.
|
|
<function>regexp_matches</function> accepts all the flags shown
|
|
in <xref linkend="posix-embedded-options-table"/>, plus
|
|
the <literal>g</literal> flag which commands it to return all matches, not
|
|
just the first one.
|
|
</para>
|
|
|
|
<para>
|
|
Some examples:
|
|
<programlisting>
|
|
SELECT regexp_matches('foo', 'not there');
|
|
regexp_matches
|
|
----------------
|
|
(0 rows)
|
|
|
|
SELECT regexp_matches('foobarbequebazilbarfbonk', '(b[^b]+)(b[^b]+)', 'g');
|
|
regexp_matches
|
|
----------------
|
|
{bar,beque}
|
|
{bazil,barf}
|
|
(2 rows)
|
|
</programlisting>
|
|
</para>
|
|
|
|
<tip>
|
|
<para>
|
|
In most cases <function>regexp_matches()</function> should be used with
|
|
the <literal>g</literal> flag, since if you only want the first match, it's
|
|
easier and more efficient to use <function>regexp_match()</function>.
|
|
However, <function>regexp_match()</function> only exists
|
|
in <productname>PostgreSQL</productname> version 10 and up. When working in older
|
|
versions, a common trick is to place a <function>regexp_matches()</function>
|
|
call in a sub-select, for example:
|
|
<programlisting>
|
|
SELECT col1, (SELECT regexp_matches(col2, '(bar)(beque)')) FROM tab;
|
|
</programlisting>
|
|
This produces a text array if there's a match, or <literal>NULL</literal> if
|
|
not, the same as <function>regexp_match()</function> would do. Without the
|
|
sub-select, this query would produce no output at all for table rows
|
|
without a match, which is typically not the desired behavior.
|
|
</para>
|
|
</tip>
|
|
|
|
<para>
|
|
The <function>regexp_split_to_table</function> 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>, <replaceable>pattern</replaceable>
|
|
<optional>, <replaceable>flags</replaceable> </optional>).
|
|
If there is no match to the <replaceable>pattern</replaceable>, the function returns the
|
|
<replaceable>string</replaceable>. 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</replaceable> 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> function behaves the same as
|
|
<function>regexp_split_to_table</function>, except that <function>regexp_split_to_array</function>
|
|
returns its result as an array of <type>text</type>. It has the syntax
|
|
<function>regexp_split_to_array</function>(<replaceable>string</replaceable>, <replaceable>pattern</replaceable>
|
|
<optional>, <replaceable>flags</replaceable> </optional>).
|
|
The parameters are the same as for <function>regexp_split_to_table</function>.
|
|
</para>
|
|
|
|
<para>
|
|
Some examples:
|
|
<programlisting>
|
|
|
|
SELECT foo FROM regexp_split_to_table('the quick brown fox jumps over the lazy dog', '\s+') AS foo;
|
|
foo
|
|
-------
|
|
the
|
|
quick
|
|
brown
|
|
fox
|
|
jumps
|
|
over
|
|
the
|
|
lazy
|
|
dog
|
|
(9 rows)
|
|
|
|
SELECT regexp_split_to_array('the quick brown fox jumps over the lazy dog', '\s+');
|
|
regexp_split_to_array
|
|
-----------------------------------------------
|
|
{the,quick,brown,fox,jumps,over,the,lazy,dog}
|
|
(1 row)
|
|
|
|
SELECT foo FROM regexp_split_to_table('the quick brown fox', '\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_match</function> and
|
|
<function>regexp_matches</function>, 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</firstterm> <acronym>RE</acronym>s or <acronym>ERE</acronym>s
|
|
(roughly those of <command>egrep</command>), and
|
|
<firstterm>basic</firstterm> <acronym>RE</acronym>s or <acronym>BRE</acronym>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</firstterm> <acronym>RE</acronym>s or <acronym>ARE</acronym>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</productname> 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</firstterm>
|
|
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</firstterm> or
|
|
<firstterm>constraints</firstterm>, 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</firstterm> possibly followed
|
|
by a single <firstterm>quantifier</firstterm>.
|
|
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</firstterm> 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>(</literal><replaceable>re</replaceable><literal>)</literal> </entry>
|
|
<entry> (where <replaceable>re</replaceable> is any regular expression)
|
|
matches a match for
|
|
<replaceable>re</replaceable>, with the match noted for possible reporting </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>(?:</literal><replaceable>re</replaceable><literal>)</literal> </entry>
|
|
<entry> as above, but the match is not noted for reporting
|
|
(a <quote>non-capturing</quote> set of parentheses)
|
|
(AREs only) </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>.</literal> </entry>
|
|
<entry> matches any single character </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>[</literal><replaceable>chars</replaceable><literal>]</literal> </entry>
|
|
<entry> a <firstterm>bracket expression</firstterm>,
|
|
matching any one of the <replaceable>chars</replaceable> (see
|
|
<xref linkend="posix-bracket-expressions"/> for more detail) </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>\</literal><replaceable>k</replaceable> </entry>
|
|
<entry> (where <replaceable>k</replaceable> is a non-alphanumeric character)
|
|
matches that character taken as an ordinary character,
|
|
e.g., <literal>\\</literal> matches a backslash character </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>\</literal><replaceable>c</replaceable> </entry>
|
|
<entry> where <replaceable>c</replaceable> is alphanumeric
|
|
(possibly followed by other characters)
|
|
is an <firstterm>escape</firstterm>, see <xref linkend="posix-escape-sequences"/>
|
|
(AREs only; in EREs and BREs, this matches <replaceable>c</replaceable>) </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>{</literal> </entry>
|
|
<entry> when followed by a character other than a digit,
|
|
matches the left-brace character <literal>{</literal>;
|
|
when followed by a digit, it is the beginning of a
|
|
<replaceable>bound</replaceable> (see below) </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <replaceable>x</replaceable> </entry>
|
|
<entry> where <replaceable>x</replaceable> is a single character with no other
|
|
significance, matches that character </entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
An RE cannot end with a backslash (<literal>\</literal>).
|
|
</para>
|
|
|
|
<note>
|
|
<para>
|
|
If you have <xref linkend="guc-standard-conforming-strings"/> turned off,
|
|
any backslashes you write in literal string constants will need to be
|
|
doubled. See <xref linkend="sql-syntax-strings"/> for more information.
|
|
</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>*</literal> </entry>
|
|
<entry> a sequence of 0 or more matches of the atom </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>+</literal> </entry>
|
|
<entry> a sequence of 1 or more matches of the atom </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>?</literal> </entry>
|
|
<entry> a sequence of 0 or 1 matches of the atom </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>{</literal><replaceable>m</replaceable><literal>}</literal> </entry>
|
|
<entry> a sequence of exactly <replaceable>m</replaceable> matches of the atom </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>{</literal><replaceable>m</replaceable><literal>,}</literal> </entry>
|
|
<entry> a sequence of <replaceable>m</replaceable> or more matches of the atom </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<literal>{</literal><replaceable>m</replaceable><literal>,</literal><replaceable>n</replaceable><literal>}</literal> </entry>
|
|
<entry> a sequence of <replaceable>m</replaceable> through <replaceable>n</replaceable>
|
|
(inclusive) matches of the atom; <replaceable>m</replaceable> cannot exceed
|
|
<replaceable>n</replaceable> </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>*?</literal> </entry>
|
|
<entry> non-greedy version of <literal>*</literal> </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>+?</literal> </entry>
|
|
<entry> non-greedy version of <literal>+</literal> </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>??</literal> </entry>
|
|
<entry> non-greedy version of <literal>?</literal> </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>{</literal><replaceable>m</replaceable><literal>}?</literal> </entry>
|
|
<entry> non-greedy version of <literal>{</literal><replaceable>m</replaceable><literal>}</literal> </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>{</literal><replaceable>m</replaceable><literal>,}?</literal> </entry>
|
|
<entry> non-greedy version of <literal>{</literal><replaceable>m</replaceable><literal>,}</literal> </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<literal>{</literal><replaceable>m</replaceable><literal>,</literal><replaceable>n</replaceable><literal>}?</literal> </entry>
|
|
<entry> non-greedy version of <literal>{</literal><replaceable>m</replaceable><literal>,</literal><replaceable>n</replaceable><literal>}</literal> </entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
The forms using <literal>{</literal><replaceable>...</replaceable><literal>}</literal>
|
|
are known as <firstterm>bounds</firstterm>.
|
|
The numbers <replaceable>m</replaceable> and <replaceable>n</replaceable> within a bound are
|
|
unsigned decimal integers with permissible values from 0 to 255 inclusive.
|
|
</para>
|
|
|
|
<para>
|
|
<firstterm>Non-greedy</firstterm> quantifiers (available in AREs only) match the
|
|
same possibilities as their corresponding normal (<firstterm>greedy</firstterm>)
|
|
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>**</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>^</literal> </entry>
|
|
<entry> matches at the beginning of the string </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>$</literal> </entry>
|
|
<entry> matches at the end of the string </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>(?=</literal><replaceable>re</replaceable><literal>)</literal> </entry>
|
|
<entry> <firstterm>positive lookahead</firstterm> matches at any point
|
|
where a substring matching <replaceable>re</replaceable> begins
|
|
(AREs only) </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>(?!</literal><replaceable>re</replaceable><literal>)</literal> </entry>
|
|
<entry> <firstterm>negative lookahead</firstterm> matches at any point
|
|
where no substring matching <replaceable>re</replaceable> begins
|
|
(AREs only) </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>(?<=</literal><replaceable>re</replaceable><literal>)</literal> </entry>
|
|
<entry> <firstterm>positive lookbehind</firstterm> matches at any point
|
|
where a substring matching <replaceable>re</replaceable> ends
|
|
(AREs only) </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>(?<!</literal><replaceable>re</replaceable><literal>)</literal> </entry>
|
|
<entry> <firstterm>negative lookbehind</firstterm> matches at any point
|
|
where no substring matching <replaceable>re</replaceable> ends
|
|
(AREs only) </entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
Lookahead and lookbehind constraints cannot contain <firstterm>back
|
|
references</firstterm> (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</emphasis> 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</productname> 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</firstterm>, 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. A character
|
|
class cannot be used as an endpoint of a range.
|
|
The <acronym>POSIX</acronym> standard defines these character class
|
|
names:
|
|
<literal>alnum</literal> (letters and numeric digits),
|
|
<literal>alpha</literal> (letters),
|
|
<literal>blank</literal> (space and tab),
|
|
<literal>cntrl</literal> (control characters),
|
|
<literal>digit</literal> (numeric digits),
|
|
<literal>graph</literal> (printable characters except space),
|
|
<literal>lower</literal> (lower-case letters),
|
|
<literal>print</literal> (printable characters including space),
|
|
<literal>punct</literal> (punctuation),
|
|
<literal>space</literal> (any white space),
|
|
<literal>upper</literal> (upper-case letters),
|
|
and <literal>xdigit</literal> (hexadecimal digits).
|
|
The behavior of these standard character classes is generally
|
|
consistent across platforms for characters in the 7-bit ASCII set.
|
|
Whether a given non-ASCII character is considered to belong to one
|
|
of these classes depends on the <firstterm>collation</firstterm>
|
|
that is used for the regular-expression function or operator
|
|
(see <xref linkend="collation"/>), or by default on the
|
|
database's <envar>LC_CTYPE</envar> locale setting (see
|
|
<xref linkend="locale"/>). The classification of non-ASCII
|
|
characters can vary across platforms even in similarly-named
|
|
locales. (But the <literal>C</literal> locale never considers any
|
|
non-ASCII characters to belong to any of these classes.)
|
|
In addition to these standard character
|
|
classes, <productname>PostgreSQL</productname> defines
|
|
the <literal>ascii</literal> character class, which contains exactly
|
|
the 7-bit ASCII set.
|
|
</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</literal> character (as
|
|
defined by the <acronym>POSIX</acronym> character class described above)
|
|
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</firstterm> are special sequences beginning with <literal>\</literal>
|
|
followed by an alphanumeric character. Escapes come in several varieties:
|
|
character entry, class shorthands, constraint escapes, and back references.
|
|
A <literal>\</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>\</literal> followed by an alphanumeric character merely stands for
|
|
that character as an ordinary character, and inside a bracket expression,
|
|
<literal>\</literal> is an ordinary character.
|
|
(The latter is the one actual incompatibility between EREs and AREs.)
|
|
</para>
|
|
|
|
<para>
|
|
<firstterm>Character-entry escapes</firstterm> 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</firstterm> 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</firstterm> 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</firstterm> (<literal>\</literal><replaceable>n</replaceable>) matches the
|
|
same string matched by the previous parenthesized subexpression specified
|
|
by the number <replaceable>n</replaceable>
|
|
(see <xref linkend="posix-constraint-backref-table"/>). For example,
|
|
<literal>([bc])\1</literal> matches <literal>bb</literal> or <literal>cc</literal>
|
|
but not <literal>bc</literal> or <literal>cb</literal>.
|
|
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>
|
|
|
|
<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</literal> </entry>
|
|
<entry> alert (bell) character, as in C </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>\b</literal> </entry>
|
|
<entry> backspace, as in C </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>\B</literal> </entry>
|
|
<entry> synonym for backslash (<literal>\</literal>) to help reduce the need for backslash
|
|
doubling </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>\c</literal><replaceable>X</replaceable> </entry>
|
|
<entry> (where <replaceable>X</replaceable> is any character) the character whose
|
|
low-order 5 bits are the same as those of
|
|
<replaceable>X</replaceable>, and whose other bits are all zero </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>\e</literal> </entry>
|
|
<entry> the character whose collating-sequence name
|
|
is <literal>ESC</literal>,
|
|
or failing that, the character with octal value <literal>033</literal> </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>\f</literal> </entry>
|
|
<entry> form feed, as in C </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>\n</literal> </entry>
|
|
<entry> newline, as in C </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>\r</literal> </entry>
|
|
<entry> carriage return, as in C </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>\t</literal> </entry>
|
|
<entry> horizontal tab, as in C </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>\u</literal><replaceable>wxyz</replaceable> </entry>
|
|
<entry> (where <replaceable>wxyz</replaceable> is exactly four hexadecimal digits)
|
|
the character whose hexadecimal value is
|
|
<literal>0x</literal><replaceable>wxyz</replaceable>
|
|
</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>\U</literal><replaceable>stuvwxyz</replaceable> </entry>
|
|
<entry> (where <replaceable>stuvwxyz</replaceable> is exactly eight hexadecimal
|
|
digits)
|
|
the character whose hexadecimal value is
|
|
<literal>0x</literal><replaceable>stuvwxyz</replaceable>
|
|
</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>\v</literal> </entry>
|
|
<entry> vertical tab, as in C </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>\x</literal><replaceable>hhh</replaceable> </entry>
|
|
<entry> (where <replaceable>hhh</replaceable> is any sequence of hexadecimal
|
|
digits)
|
|
the character whose hexadecimal value is
|
|
<literal>0x</literal><replaceable>hhh</replaceable>
|
|
(a single character no matter how many hexadecimal digits are used)
|
|
</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>\0</literal> </entry>
|
|
<entry> the character whose value is <literal>0</literal> (the null byte)</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>\</literal><replaceable>xy</replaceable> </entry>
|
|
<entry> (where <replaceable>xy</replaceable> is exactly two octal digits,
|
|
and is not a <firstterm>back reference</firstterm>)
|
|
the character whose octal value is
|
|
<literal>0</literal><replaceable>xy</replaceable> </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>\</literal><replaceable>xyz</replaceable> </entry>
|
|
<entry> (where <replaceable>xyz</replaceable> is exactly three octal digits,
|
|
and is not a <firstterm>back reference</firstterm>)
|
|
the character whose octal value is
|
|
<literal>0</literal><replaceable>xyz</replaceable> </entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
Hexadecimal digits are <literal>0</literal>-<literal>9</literal>,
|
|
<literal>a</literal>-<literal>f</literal>, and <literal>A</literal>-<literal>F</literal>.
|
|
Octal digits are <literal>0</literal>-<literal>7</literal>.
|
|
</para>
|
|
|
|
<para>
|
|
Numeric character-entry escapes specifying values outside the ASCII range
|
|
(0-127) have meanings dependent on the database encoding. When the
|
|
encoding is UTF-8, escape values are equivalent to Unicode code points,
|
|
for example <literal>\u1234</literal> means the character <literal>U+1234</literal>.
|
|
For other multibyte encodings, character-entry escapes usually just
|
|
specify the concatenation of the byte values for the character. If the
|
|
escape value does not correspond to any legal character in the database
|
|
encoding, no error will be raised, but it will never match any data.
|
|
</para>
|
|
|
|
<para>
|
|
The character-entry escapes are always taken as ordinary characters.
|
|
For example, <literal>\135</literal> is <literal>]</literal> in ASCII, but
|
|
<literal>\135</literal> 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</literal> </entry>
|
|
<entry> <literal>[[:digit:]]</literal> </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>\s</literal> </entry>
|
|
<entry> <literal>[[:space:]]</literal> </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>\w</literal> </entry>
|
|
<entry> <literal>[[:alnum:]_]</literal>
|
|
(note underscore is included) </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>\D</literal> </entry>
|
|
<entry> <literal>[^[:digit:]]</literal> </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>\S</literal> </entry>
|
|
<entry> <literal>[^[:space:]]</literal> </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>\W</literal> </entry>
|
|
<entry> <literal>[^[:alnum:]_]</literal>
|
|
(note underscore is included) </entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
Within bracket expressions, <literal>\d</literal>, <literal>\s</literal>,
|
|
and <literal>\w</literal> lose their outer brackets,
|
|
and <literal>\D</literal>, <literal>\S</literal>, and <literal>\W</literal> are illegal.
|
|
(So, for example, <literal>[a-c\d]</literal> is equivalent to
|
|
<literal>[a-c[:digit:]]</literal>.
|
|
Also, <literal>[a-c\D]</literal>, which is equivalent to
|
|
<literal>[a-c^[:digit:]]</literal>, 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</literal> </entry>
|
|
<entry> matches only at the beginning of the string
|
|
(see <xref linkend="posix-matching-rules"/> for how this differs from
|
|
<literal>^</literal>) </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>\m</literal> </entry>
|
|
<entry> matches only at the beginning of a word </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>\M</literal> </entry>
|
|
<entry> matches only at the end of a word </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>\y</literal> </entry>
|
|
<entry> matches only at the beginning or end of a word </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>\Y</literal> </entry>
|
|
<entry> matches only at a point that is not the beginning or end of a
|
|
word </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>\Z</literal> </entry>
|
|
<entry> matches only at the end of the string
|
|
(see <xref linkend="posix-matching-rules"/> for how this differs from
|
|
<literal>$</literal>) </entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
A word is defined as in the specification of
|
|
<literal>[[:<:]]</literal> and <literal>[[:>:]]</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>\</literal><replaceable>m</replaceable> </entry>
|
|
<entry> (where <replaceable>m</replaceable> is a nonzero digit)
|
|
a back reference to the <replaceable>m</replaceable>'th subexpression </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>\</literal><replaceable>mnn</replaceable> </entry>
|
|
<entry> (where <replaceable>m</replaceable> is a nonzero digit, and
|
|
<replaceable>nn</replaceable> is some more digits, and the decimal value
|
|
<replaceable>mnn</replaceable> is not greater than the number of closing capturing
|
|
parentheses seen so far)
|
|
a back reference to the <replaceable>mnn</replaceable>'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</firstterm> prefixes.
|
|
If an RE begins with <literal>***:</literal>,
|
|
the rest of the RE is taken as an ARE. (This normally has no effect in
|
|
<productname>PostgreSQL</productname>, 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</replaceable> parameter to a regex function.)
|
|
If an RE begins with <literal>***=</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</firstterm>:
|
|
a sequence <literal>(?</literal><replaceable>xyz</replaceable><literal>)</literal>
|
|
(where <replaceable>xyz</replaceable> 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</replaceable> 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</replaceable>
|
|
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</literal> </entry>
|
|
<entry> rest of RE is a BRE </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>c</literal> </entry>
|
|
<entry> case-sensitive matching (overrides operator type) </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>e</literal> </entry>
|
|
<entry> rest of RE is an ERE </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>i</literal> </entry>
|
|
<entry> case-insensitive matching (see
|
|
<xref linkend="posix-matching-rules"/>) (overrides operator type) </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>m</literal> </entry>
|
|
<entry> historical synonym for <literal>n</literal> </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>n</literal> </entry>
|
|
<entry> newline-sensitive matching (see
|
|
<xref linkend="posix-matching-rules"/>) </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>p</literal> </entry>
|
|
<entry> partial newline-sensitive matching (see
|
|
<xref linkend="posix-matching-rules"/>) </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>q</literal> </entry>
|
|
<entry> rest of RE is a literal (<quote>quoted</quote>) string, all ordinary
|
|
characters </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>s</literal> </entry>
|
|
<entry> non-newline-sensitive matching (default) </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>t</literal> </entry>
|
|
<entry> tight syntax (default; see below) </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>w</literal> </entry>
|
|
<entry> inverse partial newline-sensitive (<quote>weird</quote>) matching
|
|
(see <xref linkend="posix-matching-rules"/>) </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>x</literal> </entry>
|
|
<entry> expanded syntax (see below) </entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
Embedded options take effect at the <literal>)</literal> terminating the sequence.
|
|
They can appear only at the start of an ARE (after the
|
|
<literal>***:</literal> director if any).
|
|
</para>
|
|
|
|
<para>
|
|
In addition to the usual (<firstterm>tight</firstterm>) RE syntax, in which all
|
|
characters are significant, there is an <firstterm>expanded</firstterm> syntax,
|
|
available by specifying the embedded <literal>x</literal> option.
|
|
In the expanded syntax,
|
|
white-space characters in the RE are ignored, as are
|
|
all characters between a <literal>#</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>#</literal> preceded by <literal>\</literal> is
|
|
retained
|
|
</para>
|
|
</listitem>
|
|
<listitem>
|
|
<para>
|
|
white space or <literal>#</literal> within a bracket expression is retained
|
|
</para>
|
|
</listitem>
|
|
<listitem>
|
|
<para>
|
|
white space and comments cannot appear within multi-character symbols,
|
|
such as <literal>(?:</literal>
|
|
</para>
|
|
</listitem>
|
|
</itemizedlist>
|
|
|
|
For this purpose, white-space characters are blank, tab, newline, and
|
|
any character that belongs to the <replaceable>space</replaceable> character class.
|
|
</para>
|
|
|
|
<para>
|
|
Finally, in an ARE, outside bracket expressions, the sequence
|
|
<literal>(?#</literal><replaceable>ttt</replaceable><literal>)</literal>
|
|
(where <replaceable>ttt</replaceable> is any text not containing a <literal>)</literal>)
|
|
is a comment, completely ignored.
|
|
Again, this is not allowed between the characters of
|
|
multi-character symbols, like <literal>(?:</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</emphasis> of these metasyntax extensions is available if
|
|
an initial <literal>***=</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</firstterm> or
|
|
<firstterm>non-greedy</firstterm>.
|
|
</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>{</literal><replaceable>m</replaceable><literal>}</literal>
|
|
or
|
|
<literal>{</literal><replaceable>m</replaceable><literal>}?</literal>)
|
|
has the same greediness (possibly none) as the atom itself.
|
|
</para>
|
|
</listitem>
|
|
<listitem>
|
|
<para>
|
|
A quantified atom with other normal quantifiers (including
|
|
<literal>{</literal><replaceable>m</replaceable><literal>,</literal><replaceable>n</replaceable><literal>}</literal>
|
|
with <replaceable>m</replaceable> equal to <replaceable>n</replaceable>)
|
|
is greedy (prefers longest match).
|
|
</para>
|
|
</listitem>
|
|
<listitem>
|
|
<para>
|
|
A quantified atom with a non-greedy quantifier (including
|
|
<literal>{</literal><replaceable>m</replaceable><literal>,</literal><replaceable>n</replaceable><literal>}?</literal>
|
|
with <replaceable>m</replaceable> equal to <replaceable>n</replaceable>)
|
|
is non-greedy (prefers shortest match).
|
|
</para>
|
|
</listitem>
|
|
<listitem>
|
|
<para>
|
|
A branch — that is, an RE that has no top-level
|
|
<literal>|</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>|</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</emphasis>. 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*</literal>
|
|
is greedy. It can match beginning at the <literal>Y</literal>, and it matches
|
|
the longest possible string starting there, i.e., <literal>Y123</literal>.
|
|
The output is the parenthesized part of that, or <literal>123</literal>.
|
|
In the second case, the RE as a whole is non-greedy because <literal>Y*?</literal>
|
|
is non-greedy. It can match beginning at the <literal>Y</literal>, and it matches
|
|
the shortest possible string starting there, i.e., <literal>Y1</literal>.
|
|
The subexpression <literal>[0-9]{1,3}</literal> is greedy but it cannot change
|
|
the decision as to the overall match length; so it is forced to match
|
|
just <literal>1</literal>.
|
|
</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</quote> relative to each other.
|
|
</para>
|
|
|
|
<para>
|
|
The quantifiers <literal>{1,1}</literal> and <literal>{1,1}?</literal>
|
|
can be used to force greediness or non-greediness, respectively,
|
|
on a subexpression or a whole RE.
|
|
This is useful when you need the whole RE to have a greediness attribute
|
|
different from what's deduced from its elements. As an example,
|
|
suppose that we are trying to separate a string containing some digits
|
|
into the digits and the parts before and after them. We might try to
|
|
do that like this:
|
|
<screen>
|
|
SELECT regexp_match('abc01234xyz', '(.*)(\d+)(.*)');
|
|
<lineannotation>Result: </lineannotation><computeroutput>{abc0123,4,xyz}</computeroutput>
|
|
</screen>
|
|
That didn't work: the first <literal>.*</literal> is greedy so
|
|
it <quote>eats</quote> as much as it can, leaving the <literal>\d+</literal> to
|
|
match at the last possible place, the last digit. We might try to fix
|
|
that by making it non-greedy:
|
|
<screen>
|
|
SELECT regexp_match('abc01234xyz', '(.*?)(\d+)(.*)');
|
|
<lineannotation>Result: </lineannotation><computeroutput>{abc,0,""}</computeroutput>
|
|
</screen>
|
|
That didn't work either, because now the RE as a whole is non-greedy
|
|
and so it ends the overall match as soon as possible. We can get what
|
|
we want by forcing the RE as a whole to be greedy:
|
|
<screen>
|
|
SELECT regexp_match('abc01234xyz', '(?:(.*?)(\d+)(.*)){1,1}');
|
|
<lineannotation>Result: </lineannotation><computeroutput>{abc,01234,xyz}</computeroutput>
|
|
</screen>
|
|
Controlling the RE's overall greediness separately from its components'
|
|
greediness allows great flexibility in handling variable-length patterns.
|
|
</para>
|
|
|
|
<para>
|
|
When deciding what is a longer or shorter match,
|
|
match lengths are measured in characters, not collating elements.
|
|
An empty string is considered longer than no match at all.
|
|
For example:
|
|
<literal>bb*</literal>
|
|
matches the three middle characters of <literal>abbbc</literal>;
|
|
<literal>(week|wee)(night|knights)</literal>
|
|
matches all ten characters of <literal>weeknights</literal>;
|
|
when <literal>(.*).*</literal>
|
|
is matched against <literal>abc</literal> the parenthesized subexpression
|
|
matches all three characters; and when
|
|
<literal>(a*)*</literal> is matched against <literal>bc</literal>
|
|
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</literal> becomes <literal>[xX]</literal>.
|
|
When it appears inside a bracket expression, all case counterparts
|
|
of it are added to the bracket expression, e.g.,
|
|
<literal>[x]</literal> becomes <literal>[xX]</literal>
|
|
and <literal>[^x]</literal> becomes <literal>[^xX]</literal>.
|
|
</para>
|
|
|
|
<para>
|
|
If newline-sensitive matching is specified, <literal>.</literal>
|
|
and bracket expressions using <literal>^</literal>
|
|
will never match the newline character
|
|
(so that matches will never cross newlines unless the RE
|
|
explicitly arranges it)
|
|
and <literal>^</literal> and <literal>$</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</literal> and <literal>\Z</literal>
|
|
continue to match beginning or end of string <emphasis>only</emphasis>.
|
|
</para>
|
|
|
|
<para>
|
|
If partial newline-sensitive matching is specified,
|
|
this affects <literal>.</literal> and bracket expressions
|
|
as with newline-sensitive matching, but not <literal>^</literal>
|
|
and <literal>$</literal>.
|
|
</para>
|
|
|
|
<para>
|
|
If inverse partial newline-sensitive matching is specified,
|
|
this affects <literal>^</literal> and <literal>$</literal>
|
|
as with newline-sensitive matching, but not <literal>.</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>\</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>***</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>, <literal>\B</literal>,
|
|
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/lookbehind
|
|
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</productname>:
|
|
|
|
<itemizedlist>
|
|
<listitem>
|
|
<para>
|
|
In AREs, <literal>\</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>\</literal> remains a special character within
|
|
<literal>[]</literal>, so a literal <literal>\</literal> within a bracket
|
|
expression must be written <literal>\\</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>, <literal>+</literal>, and <literal>?</literal>
|
|
are ordinary characters and there is no equivalent
|
|
for their functionality.
|
|
The delimiters for bounds are
|
|
<literal>\{</literal> and <literal>\}</literal>,
|
|
with <literal>{</literal> and <literal>}</literal>
|
|
by themselves ordinary characters.
|
|
The parentheses for nested subexpressions are
|
|
<literal>\(</literal> and <literal>\)</literal>,
|
|
with <literal>(</literal> and <literal>)</literal> by themselves ordinary characters.
|
|
<literal>^</literal> is an ordinary character except at the beginning of the
|
|
RE or the beginning of a parenthesized subexpression,
|
|
<literal>$</literal> is an ordinary character except at the end of the
|
|
RE or the end of a parenthesized subexpression,
|
|
and <literal>*</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>^</literal>).
|
|
Finally, single-digit back references are available, and
|
|
<literal>\<</literal> and <literal>\></literal>
|
|
are synonyms for
|
|
<literal>[[:<:]]</literal> and <literal>[[:>:]]</literal>
|
|
respectively; no other escapes are available in BREs.
|
|
</para>
|
|
</sect3>
|
|
|
|
<!-- end re_syntax.n man page -->
|
|
|
|
<sect3 id="posix-vs-xquery">
|
|
<title>Differences From XQuery (<literal>LIKE_REGEX</literal>)</title>
|
|
|
|
<indexterm zone="posix-vs-xquery">
|
|
<primary><literal>LIKE_REGEX</literal></primary>
|
|
</indexterm>
|
|
|
|
<indexterm zone="posix-vs-xquery">
|
|
<primary>XQuery regular expressions</primary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
Since SQL:2008, the SQL standard includes
|
|
a <literal>LIKE_REGEX</literal> operator that performs pattern
|
|
matching according to the XQuery regular expression
|
|
standard. <productname>PostgreSQL</productname> does not yet
|
|
implement this operator, but you can get very similar behavior using
|
|
the <function>regexp_match()</function> function, since XQuery
|
|
regular expressions are quite close to the ARE syntax described above.
|
|
</para>
|
|
|
|
<para>
|
|
Notable differences between the existing POSIX-based
|
|
regular-expression feature and XQuery regular expressions include:
|
|
|
|
<itemizedlist>
|
|
<listitem>
|
|
<para>
|
|
XQuery character class subtraction is not supported. An example of
|
|
this feature is using the following to match only English
|
|
consonants: <literal>[a-z-[aeiou]]</literal>.
|
|
</para>
|
|
</listitem>
|
|
<listitem>
|
|
<para>
|
|
XQuery character class shorthands <literal>\c</literal>,
|
|
<literal>\C</literal>, <literal>\i</literal>,
|
|
and <literal>\I</literal> are not supported.
|
|
</para>
|
|
</listitem>
|
|
<listitem>
|
|
<para>
|
|
XQuery character class elements
|
|
using <literal>\p{UnicodeProperty}</literal> or the
|
|
inverse <literal>\P{UnicodeProperty}</literal> are not supported.
|
|
</para>
|
|
</listitem>
|
|
<listitem>
|
|
<para>
|
|
POSIX interprets character classes such as <literal>\w</literal>
|
|
(see <xref linkend="posix-class-shorthand-escapes-table"/>)
|
|
according to the prevailing locale (which you can control by
|
|
attaching a <literal>COLLATE</literal> clause to the operator or
|
|
function). XQuery specifies these classes by reference to Unicode
|
|
character properties, so equivalent behavior is obtained only with
|
|
a locale that follows the Unicode rules.
|
|
</para>
|
|
</listitem>
|
|
<listitem>
|
|
<para>
|
|
The SQL standard (not XQuery itself) attempts to cater for more
|
|
variants of <quote>newline</quote> than POSIX does. The
|
|
newline-sensitive matching options described above consider only
|
|
ASCII NL (<literal>\n</literal>) to be a newline, but SQL would have
|
|
us treat CR (<literal>\r</literal>), CRLF (<literal>\r\n</literal>)
|
|
(a Windows-style newline), and some Unicode-only characters like
|
|
LINE SEPARATOR (U+2028) as newlines as well.
|
|
Notably, <literal>.</literal> and <literal>\s</literal> should
|
|
count <literal>\r\n</literal> as one character not two according to
|
|
SQL.
|
|
</para>
|
|
</listitem>
|
|
<listitem>
|
|
<para>
|
|
Of the character-entry escapes described in
|
|
<xref linkend="posix-character-entry-escapes-table"/>,
|
|
XQuery supports only <literal>\n</literal>, <literal>\r</literal>,
|
|
and <literal>\t</literal>.
|
|
</para>
|
|
</listitem>
|
|
<listitem>
|
|
<para>
|
|
XQuery does not support
|
|
the <literal>[:<replaceable>name</replaceable>:]</literal> syntax
|
|
for character classes within bracket expressions.
|
|
</para>
|
|
</listitem>
|
|
<listitem>
|
|
<para>
|
|
XQuery does not have lookahead or lookbehind constraints,
|
|
nor any of the constraint escapes described in
|
|
<xref linkend="posix-constraint-escapes-table"/>.
|
|
</para>
|
|
</listitem>
|
|
<listitem>
|
|
<para>
|
|
The metasyntax forms described in <xref linkend="posix-metasyntax"/>
|
|
do not exist in XQuery.
|
|
</para>
|
|
</listitem>
|
|
<listitem>
|
|
<para>
|
|
The regular expression flag letters defined by XQuery are
|
|
related to but not the same as the option letters for POSIX
|
|
(<xref linkend="posix-embedded-options-table"/>). While the
|
|
<literal>i</literal> and <literal>q</literal> options behave the
|
|
same, others do not:
|
|
<itemizedlist>
|
|
<listitem>
|
|
<para>
|
|
XQuery's <literal>s</literal> (allow dot to match newline)
|
|
and <literal>m</literal> (allow <literal>^</literal>
|
|
and <literal>$</literal> to match at newlines) flags provide
|
|
access to the same behaviors as
|
|
POSIX's <literal>n</literal>, <literal>p</literal>
|
|
and <literal>w</literal> flags, but they
|
|
do <emphasis>not</emphasis> match the behavior of
|
|
POSIX's <literal>s</literal> and <literal>m</literal> flags.
|
|
Note in particular that dot-matches-newline is the default
|
|
behavior in POSIX but not XQuery.
|
|
</para>
|
|
</listitem>
|
|
<listitem>
|
|
<para>
|
|
XQuery's <literal>x</literal> (ignore whitespace in pattern) flag
|
|
is noticeably different from POSIX's expanded-mode flag.
|
|
POSIX's <literal>x</literal> flag also
|
|
allows <literal>#</literal> to begin a comment in the pattern,
|
|
and POSIX will not ignore a whitespace character after a
|
|
backslash.
|
|
</para>
|
|
</listitem>
|
|
</itemizedlist>
|
|
</para>
|
|
</listitem>
|
|
</itemizedlist>
|
|
</para>
|
|
|
|
</sect3>
|
|
</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>
|
|
|
|
<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>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<note>
|
|
<para>
|
|
There is also a single-argument <function>to_timestamp</function>
|
|
function; see <xref linkend="functions-datetime-table"/>.
|
|
</para>
|
|
</note>
|
|
|
|
<tip>
|
|
<para>
|
|
<function>to_timestamp</function> and <function>to_date</function>
|
|
exist to handle input formats that cannot be converted by
|
|
simple casting. For most standard date/time formats, simply casting the
|
|
source string to the required data type works, and is much easier.
|
|
Similarly, <function>to_number</function> is unnecessary for standard numeric
|
|
representations.
|
|
</para>
|
|
</tip>
|
|
|
|
<para>
|
|
In a <function>to_char</function> 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. If there are characters in the template string
|
|
that are not template patterns, the corresponding characters in the input
|
|
data string are simply skipped over (whether or not they are equal to the
|
|
template string characters).
|
|
</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 or more digits) with comma</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>YYYY</literal></entry>
|
|
<entry>year (4 or 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 8601 week-numbering year (4 or more digits)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>IYY</literal></entry>
|
|
<entry>last 3 digits of ISO 8601 week-numbering year</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>IY</literal></entry>
|
|
<entry>last 2 digits of ISO 8601 week-numbering year</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>I</literal></entry>
|
|
<entry>last digit of ISO 8601 week-numbering 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>day of ISO 8601 week-numbering 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</literal>) to Saturday (<literal>7</literal>)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>ID</literal></entry>
|
|
<entry>ISO 8601 day of the week, Monday (<literal>1</literal>) to Sunday (<literal>7</literal>)</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>week number of ISO 8601 week-numbering year (01-53; the first Thursday of the 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 (integer days since November 24, 4714 BC at midnight UTC)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>Q</literal></entry>
|
|
<entry>quarter</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 abbreviation
|
|
(only supported in <function>to_char</function>)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>tz</literal></entry>
|
|
<entry>lower case time-zone abbreviation
|
|
(only supported in <function>to_char</function>)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>TZH</literal></entry>
|
|
<entry>time-zone hours</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>TZM</literal></entry>
|
|
<entry>time-zone minutes</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>OF</literal></entry>
|
|
<entry>time-zone offset from UTC
|
|
(only supported in <function>to_char</function>)</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 leading zeroes and padding blanks)</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</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>th</literal> suffix</entry>
|
|
<entry>lower case ordinal number suffix</entry>
|
|
<entry><literal>DDth</literal>, e.g., <literal>12th</literal></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.
|
|
<function>to_timestamp</function> and <function>to_date</function> ignore
|
|
the <literal>TM</literal> modifier.
|
|
</para>
|
|
</listitem>
|
|
|
|
<listitem>
|
|
<para>
|
|
<function>to_timestamp</function> and <function>to_date</function>
|
|
skip multiple blank spaces at the beginning of the input string and
|
|
around date and time values unless the <literal>FX</literal> option is used. For example,
|
|
<literal>to_timestamp(' 2000 JUN', 'YYYY MON')</literal> and
|
|
<literal>to_timestamp('2000 - JUN', 'YYYY-MON')</literal> work, but
|
|
<literal>to_timestamp('2000 JUN', 'FXYYYY MON')</literal> returns an error
|
|
because <function>to_timestamp</function> expects only a single space.
|
|
<literal>FX</literal> must be specified as the first item in
|
|
the template.
|
|
</para>
|
|
</listitem>
|
|
|
|
<listitem>
|
|
<para>
|
|
A separator (a space or non-letter/non-digit character) in the template string of
|
|
<function>to_timestamp</function> and <function>to_date</function>
|
|
matches any single separator in the input string or is skipped,
|
|
unless the <literal>FX</literal> option is used.
|
|
For example, <literal>to_timestamp('2000JUN', 'YYYY///MON')</literal> and
|
|
<literal>to_timestamp('2000/JUN', 'YYYY MON')</literal> work, but
|
|
<literal>to_timestamp('2000//JUN', 'YYYY/MON')</literal>
|
|
returns an error because the number of separators in the input string
|
|
exceeds the number of separators in the template.
|
|
</para>
|
|
<para>
|
|
If <literal>FX</literal> is specified, a separator in the template string
|
|
matches exactly one character in the input string. But note that the
|
|
input string character is not required to be the same as the separator from the template string.
|
|
For example, <literal>to_timestamp('2000/JUN', 'FXYYYY MON')</literal>
|
|
works, but <literal>to_timestamp('2000/JUN', 'FXYYYY MON')</literal>
|
|
returns an error because the second space in the template string consumes
|
|
the letter <literal>J</literal> from the input string.
|
|
</para>
|
|
</listitem>
|
|
|
|
<listitem>
|
|
<para>
|
|
A <literal>TZH</literal> template pattern can match a signed number.
|
|
Without the <literal>FX</literal> option, minus signs may be ambiguous,
|
|
and could be interpreted as a separator.
|
|
This ambiguity is resolved as follows: If the number of separators before
|
|
<literal>TZH</literal> in the template string is less than the number of
|
|
separators before the minus sign in the input string, the minus sign
|
|
is interpreted as part of <literal>TZH</literal>.
|
|
Otherwise, the minus sign is considered to be a separator between values.
|
|
For example, <literal>to_timestamp('2000 -10', 'YYYY TZH')</literal> matches
|
|
<literal>-10</literal> to <literal>TZH</literal>, but
|
|
<literal>to_timestamp('2000 -10', 'YYYY TZH')</literal>
|
|
matches <literal>10</literal> to <literal>TZH</literal>.
|
|
</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 template patterns. 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>, <function>to_number</function>,
|
|
and <function>to_timestamp</function>, literal text and double-quoted
|
|
strings result in skipping the number of characters contained in the
|
|
string; for example <literal>"XX"</literal> skips two input characters
|
|
(whether or not they are <literal>XX</literal>).
|
|
</para>
|
|
<tip>
|
|
<para>
|
|
Prior to <productname>PostgreSQL</productname> 12, it was possible to
|
|
skip arbitrary text in the input string using non-letter or non-digit
|
|
characters. For example,
|
|
<literal>to_timestamp('2000y6m1d', 'yyyy-MM-DD')</literal> used to
|
|
work. Now you can only use letter characters for this purpose. For example,
|
|
<literal>to_timestamp('2000y6m1d', 'yyyytMMtDDt')</literal> and
|
|
<literal>to_timestamp('2000y6m1d', 'yyyy"y"MM"m"DD"d"')</literal>
|
|
skip <literal>y</literal>, <literal>m</literal>, and
|
|
<literal>d</literal>.
|
|
</para>
|
|
</tip>
|
|
</listitem>
|
|
|
|
<listitem>
|
|
<para>
|
|
If you want to have a double quote in the output you must
|
|
precede it with a backslash, for example <literal>'\"YYYY
|
|
Month\"'</literal>. <!-- "" font-lock sanity :-) -->
|
|
Backslashes are not otherwise special outside of double-quoted
|
|
strings. Within a double-quoted string, a backslash causes the
|
|
next character to be taken literally, whatever it is (but this
|
|
has no special effect unless the next character is a double quote
|
|
or another backslash).
|
|
</para>
|
|
</listitem>
|
|
|
|
<listitem>
|
|
<para>
|
|
In <function>to_timestamp</function> and <function>to_date</function>,
|
|
if the year format specification is less than four digits, e.g.
|
|
<literal>YYY</literal>, and the supplied year is less than four digits,
|
|
the year will be adjusted to be nearest to the year 2020, e.g.
|
|
<literal>95</literal> becomes 1995.
|
|
</para>
|
|
</listitem>
|
|
|
|
<listitem>
|
|
<para>
|
|
In <function>to_timestamp</function> and <function>to_date</function>,
|
|
the <literal>YYYY</literal> conversion 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 <function>to_timestamp</function> and <function>to_date</function>,
|
|
the <literal>CC</literal> (century) field is accepted but 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 result is
|
|
computed as that year in the specified century. If the century is
|
|
specified but the year is not, the first year of the century
|
|
is assumed.
|
|
</para>
|
|
</listitem>
|
|
|
|
<listitem>
|
|
<para>
|
|
In <function>to_timestamp</function> and <function>to_date</function>,
|
|
weekday names or numbers (<literal>DAY</literal>, <literal>D</literal>,
|
|
and related field types) are accepted but are ignored for purposes of
|
|
computing the result. The same is true for quarter
|
|
(<literal>Q</literal>) fields.
|
|
</para>
|
|
</listitem>
|
|
|
|
<listitem>
|
|
<para>
|
|
In <function>to_timestamp</function> and <function>to_date</function>,
|
|
an ISO 8601 week-numbering date (as distinct from a Gregorian date)
|
|
can be specified in one of two ways:
|
|
<itemizedlist>
|
|
<listitem>
|
|
<para>
|
|
Year, week number, 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 enter a date using a mixture of ISO 8601 week-numbering
|
|
fields and Gregorian date fields is nonsensical, and will cause an
|
|
error. In the context of an ISO 8601 week-numbering year, the
|
|
concept of a <quote>month</quote> or <quote>day of month</quote> has no
|
|
meaning. In the context of a Gregorian year, the ISO week has no
|
|
meaning.
|
|
</para>
|
|
<caution>
|
|
<para>
|
|
While <function>to_date</function> will reject a mixture of
|
|
Gregorian and ISO week-numbering date
|
|
fields, <function>to_char</function> will not, since output format
|
|
specifications like <literal>YYYY-MM-DD (IYYY-IDDD)</literal> can be
|
|
useful. But avoid writing something like <literal>IYYY-MM-DD</literal>;
|
|
that would yield surprising results near the start of the year.
|
|
(See <xref linkend="functions-datetime-extract"/> for more
|
|
information.)
|
|
</para>
|
|
</caution>
|
|
</listitem>
|
|
|
|
<listitem>
|
|
<para>
|
|
In <function>to_timestamp</function>, millisecond
|
|
(<literal>MS</literal>) or microsecond (<literal>US</literal>)
|
|
fields 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 treats it as 12 + 0.3 seconds.
|
|
So, 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 write
|
|
<literal>12.003</literal>, which the conversion treats as
|
|
12 + 0.003 = 12.003 seconds.
|
|
</para>
|
|
|
|
<para>
|
|
Here is a more
|
|
complex example:
|
|
<literal>to_timestamp('15:12:02.020.001230', 'HH24: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</literal> and
|
|
<literal>HH12</literal> as shown on a 12-hour clock, for example zero hours
|
|
and 36 hours both output as <literal>12</literal>, while <literal>HH24</literal>
|
|
outputs the full hour value, which can exceed 23 in
|
|
an <type>interval</type> value.
|
|
</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>digit position (can be dropped if insignificant)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>0</literal></entry>
|
|
<entry>digit position (will not be dropped, even if insignificant)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>.</literal> (period)</entry>
|
|
<entry>decimal point</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>,</literal> (comma)</entry>
|
|
<entry>group (thousands) 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>
|
|
<literal>0</literal> specifies a digit position that will always be printed,
|
|
even if it contains a leading/trailing zero. <literal>9</literal> also
|
|
specifies a digit position, but if it is a leading zero then it will
|
|
be replaced by a space, while if it is a trailing zero and fill mode
|
|
is specified then it will be deleted. (For <function>to_number()</function>,
|
|
these two pattern characters are equivalent.)
|
|
</para>
|
|
</listitem>
|
|
|
|
<listitem>
|
|
<para>
|
|
The pattern characters <literal>S</literal>, <literal>L</literal>, <literal>D</literal>,
|
|
and <literal>G</literal> represent the sign, currency symbol, decimal point,
|
|
and thousands separator characters defined by the current locale
|
|
(see <xref linkend="guc-lc-monetary"/>
|
|
and <xref linkend="guc-lc-numeric"/>). The pattern characters period
|
|
and comma represent those exact characters, with the meanings of
|
|
decimal point and thousands separator, regardless of locale.
|
|
</para>
|
|
</listitem>
|
|
|
|
<listitem>
|
|
<para>
|
|
If no explicit provision is made for a sign
|
|
in <function>to_char()</function>'s pattern, one column will be reserved for
|
|
the sign, and it will be anchored to (appear just left of) the
|
|
number. If <literal>S</literal> appears just left of some <literal>9</literal>'s,
|
|
it will likewise be anchored to the number.
|
|
</para>
|
|
</listitem>
|
|
|
|
<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>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>
|
|
In <function>to_number</function>, if non-data template patterns such
|
|
as <literal>L</literal> or <literal>TH</literal> are used, the
|
|
corresponding number of input characters are skipped, whether or not
|
|
they match the template pattern, unless they are data characters
|
|
(that is, digits, sign, decimal point, or comma). For
|
|
example, <literal>TH</literal> would skip two non-data characters.
|
|
</para>
|
|
</listitem>
|
|
|
|
<listitem>
|
|
<para>
|
|
<literal>V</literal> with <function>to_char</function>
|
|
multiplies the input values by
|
|
<literal>10^<replaceable>n</replaceable></literal>, where
|
|
<replaceable>n</replaceable> is the number of digits following
|
|
<literal>V</literal>. <literal>V</literal> with
|
|
<function>to_number</function> divides in a similar manner.
|
|
<function>to_char</function> and <function>to_number</function>
|
|
do 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>FM99.99</literal>
|
|
is the <literal>99.99</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 trailing zeroes and padding blanks)</entry>
|
|
<entry><literal>FM99.99</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, 'FM90.99')</literal></entry>
|
|
<entry><literal>'-0.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>+</literal> and <literal>*</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</quote> result that
|
|
uses years and months, rather than just days</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 <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><literal><function>date_trunc(<type>text</type>, <type>timestamp with time zone</type>, <type>text</type>)</function></literal></entry>
|
|
<entry><type>timestamp with time zone</type></entry>
|
|
<entry>Truncate to specified precision in the specified time zone; see <xref linkend="functions-datetime-trunc"/>
|
|
</entry>
|
|
<entry><literal>date_trunc('day', timestamptz '2001-02-16 20:38:40+00', 'Australia/Sydney')</literal></entry>
|
|
<entry><literal>2001-02-16 13:00:00+00</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal><function>date_trunc(<type>text</type>, <type>interval</type>)</function></literal></entry>
|
|
<entry><type>interval</type></entry>
|
|
<entry>Truncate to specified precision; see <xref linkend="functions-datetime-trunc"/>
|
|
</entry>
|
|
<entry><literal>date_trunc('hour', interval '2 days 3 hours 40 minutes')</literal></entry>
|
|
<entry><literal>2 days 03: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</function> and <function>justify_hours</function>, 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>make_date</primary>
|
|
</indexterm>
|
|
<literal>
|
|
<function>
|
|
make_date(<parameter>year</parameter> <type>int</type>,
|
|
<parameter>month</parameter> <type>int</type>,
|
|
<parameter>day</parameter> <type>int</type>)
|
|
</function>
|
|
</literal>
|
|
</entry>
|
|
<entry><type>date</type></entry>
|
|
<entry>
|
|
Create date from year, month and day fields
|
|
</entry>
|
|
<entry><literal>make_date(2013, 7, 15)</literal></entry>
|
|
<entry><literal>2013-07-15</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>make_interval</primary>
|
|
</indexterm>
|
|
<literal>
|
|
<function>
|
|
make_interval(<parameter>years</parameter> <type>int</type> DEFAULT 0,
|
|
<parameter>months</parameter> <type>int</type> DEFAULT 0,
|
|
<parameter>weeks</parameter> <type>int</type> DEFAULT 0,
|
|
<parameter>days</parameter> <type>int</type> DEFAULT 0,
|
|
<parameter>hours</parameter> <type>int</type> DEFAULT 0,
|
|
<parameter>mins</parameter> <type>int</type> DEFAULT 0,
|
|
<parameter>secs</parameter> <type>double precision</type> DEFAULT 0.0)
|
|
</function>
|
|
</literal>
|
|
</entry>
|
|
<entry><type>interval</type></entry>
|
|
<entry>
|
|
Create interval from years, months, weeks, days, hours, minutes and
|
|
seconds fields
|
|
</entry>
|
|
<entry><literal>make_interval(days => 10)</literal></entry>
|
|
<entry><literal>10 days</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>make_time</primary>
|
|
</indexterm>
|
|
<literal>
|
|
<function>
|
|
make_time(<parameter>hour</parameter> <type>int</type>,
|
|
<parameter>min</parameter> <type>int</type>,
|
|
<parameter>sec</parameter> <type>double precision</type>)
|
|
</function>
|
|
</literal>
|
|
</entry>
|
|
<entry><type>time</type></entry>
|
|
<entry>
|
|
Create time from hour, minute and seconds fields
|
|
</entry>
|
|
<entry><literal>make_time(8, 15, 23.5)</literal></entry>
|
|
<entry><literal>08:15:23.5</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>make_timestamp</primary>
|
|
</indexterm>
|
|
<literal>
|
|
<function>
|
|
make_timestamp(<parameter>year</parameter> <type>int</type>,
|
|
<parameter>month</parameter> <type>int</type>,
|
|
<parameter>day</parameter> <type>int</type>,
|
|
<parameter>hour</parameter> <type>int</type>,
|
|
<parameter>min</parameter> <type>int</type>,
|
|
<parameter>sec</parameter> <type>double precision</type>)
|
|
</function>
|
|
</literal>
|
|
</entry>
|
|
<entry><type>timestamp</type></entry>
|
|
<entry>
|
|
Create timestamp from year, month, day, hour, minute and seconds fields
|
|
</entry>
|
|
<entry><literal>make_timestamp(2013, 7, 15, 8, 15, 23.5)</literal></entry>
|
|
<entry><literal>2013-07-15 08:15:23.5</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>make_timestamptz</primary>
|
|
</indexterm>
|
|
<literal>
|
|
<function>
|
|
make_timestamptz(<parameter>year</parameter> <type>int</type>,
|
|
<parameter>month</parameter> <type>int</type>,
|
|
<parameter>day</parameter> <type>int</type>,
|
|
<parameter>hour</parameter> <type>int</type>,
|
|
<parameter>min</parameter> <type>int</type>,
|
|
<parameter>sec</parameter> <type>double precision</type>,
|
|
<optional> <parameter>timezone</parameter> <type>text</type> </optional>)
|
|
</function>
|
|
</literal>
|
|
</entry>
|
|
<entry><type>timestamp with time zone</type></entry>
|
|
<entry>
|
|
Create timestamp with time zone from year, month, day, hour, minute
|
|
and seconds fields; if <parameter>timezone</parameter> is not
|
|
specified, the current time zone is used
|
|
</entry>
|
|
<entry><literal>make_timestamptz(2013, 7, 15, 8, 15, 23.5)</literal></entry>
|
|
<entry><literal>2013-07-15 08:15:23.5+01</literal></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</function>, but as a <type>text</type> 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>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>to_timestamp</primary>
|
|
</indexterm>
|
|
<literal><function>to_timestamp(<type>double precision</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>timestamp with time zone</type></entry>
|
|
<entry>Convert Unix epoch (seconds since 1970-01-01 00:00:00+00) to
|
|
timestamp</entry>
|
|
<entry><literal>to_timestamp(1284352323)</literal></entry>
|
|
<entry><literal>2010-09-13 04:32:03+00</literal></entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
<indexterm>
|
|
<primary>OVERLAPS</primary>
|
|
</indexterm>
|
|
In addition to these functions, the SQL <literal>OVERLAPS</literal> 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</literal> automatically takes the earlier value
|
|
of the pair as the start. Each time period is considered to
|
|
represent the half-open interval <replaceable>start</replaceable> <literal><=</literal>
|
|
<replaceable>time</replaceable> <literal><</literal> <replaceable>end</replaceable>, unless
|
|
<replaceable>start</replaceable> and <replaceable>end</replaceable> 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 (when the session time zone is 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</literal> field returned by
|
|
<function>age</function> because different months have different numbers of
|
|
days. <productname>PostgreSQL</productname>'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')</literal> uses April to yield
|
|
<literal>1 mon 1 day</literal>, while using May would yield <literal>1 mon 2
|
|
days</literal> because May has 31 days, while April has only 30.
|
|
</para>
|
|
|
|
<para>
|
|
Subtraction of dates and timestamps can also be complex. One conceptually
|
|
simple way to perform subtraction is to convert each value to a number
|
|
of seconds using <literal>EXTRACT(EPOCH FROM ...)</literal>, then subtract the
|
|
results; this produces the
|
|
number of <emphasis>seconds</emphasis> between the two values. This will adjust
|
|
for the number of days in each month, timezone changes, and daylight
|
|
saving time adjustments. Subtraction of date or timestamp
|
|
values with the <quote><literal>-</literal></quote> operator
|
|
returns the number of days (24-hours) and hours/minutes/seconds
|
|
between the values, making the same adjustments. The <function>age</function>
|
|
function returns years, months, days, and hours/minutes/seconds,
|
|
performing field-by-field subtraction and then adjusting for negative
|
|
field values. The following queries illustrate the differences in these
|
|
approaches. The sample results were produced with <literal>timezone
|
|
= 'US/Eastern'</literal>; there is a daylight saving time change between the
|
|
two dates used:
|
|
</para>
|
|
|
|
<screen>
|
|
SELECT EXTRACT(EPOCH FROM timestamptz '2013-07-01 12:00:00') -
|
|
EXTRACT(EPOCH FROM timestamptz '2013-03-01 12:00:00');
|
|
<lineannotation>Result: </lineannotation><computeroutput>10537200</computeroutput>
|
|
SELECT (EXTRACT(EPOCH FROM timestamptz '2013-07-01 12:00:00') -
|
|
EXTRACT(EPOCH FROM timestamptz '2013-03-01 12:00:00'))
|
|
/ 60 / 60 / 24;
|
|
<lineannotation>Result: </lineannotation><computeroutput>121.958333333333</computeroutput>
|
|
SELECT timestamptz '2013-07-01 12:00:00' - timestamptz '2013-03-01 12:00:00';
|
|
<lineannotation>Result: </lineannotation><computeroutput>121 days 23:00:00</computeroutput>
|
|
SELECT age(timestamptz '2013-07-01 12:00:00', timestamptz '2013-03-01 12:00:00');
|
|
<lineannotation>Result: </lineannotation><computeroutput>4 mons</computeroutput>
|
|
</screen>
|
|
|
|
<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>
|
|
</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</literal>) to
|
|
Saturday (<literal>6</literal>)
|
|
</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>timestamp with time zone</type> values, the
|
|
number of seconds since 1970-01-01 00:00:00 UTC (can be negative);
|
|
for <type>date</type> and <type>timestamp</type> values, the
|
|
number of seconds since 1970-01-01 00:00:00 local time;
|
|
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>
|
|
You can convert an epoch value back to a time stamp
|
|
with <function>to_timestamp</function>:
|
|
</para>
|
|
<screen>
|
|
SELECT to_timestamp(982384720.12);
|
|
<lineannotation>Result: </lineannotation><computeroutput>2001-02-17 04:38:40.12+00</computeroutput>
|
|
</screen>
|
|
</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</literal>) to
|
|
Sunday (<literal>7</literal>)
|
|
</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</literal> except for Sunday. This
|
|
matches the <acronym>ISO</acronym> 8601 day of the week numbering.
|
|
</para>
|
|
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>isoyear</literal></term>
|
|
<listitem>
|
|
<para>
|
|
The <acronym>ISO</acronym> 8601 week-numbering 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> 8601 week-numbering 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>
|
|
</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. (Technically,
|
|
<productname>PostgreSQL</productname> does not use UTC because
|
|
leap seconds are not handled.)
|
|
</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 <acronym>ISO</acronym> 8601 week-numbering week of
|
|
the year. By definition, ISO weeks start on Mondays and the first
|
|
week of a year contains January 4 of that year. In other words, the
|
|
first Thursday of a year is in week 1 of that year.
|
|
</para>
|
|
<para>
|
|
In the ISO week-numbering system, it is possible for early-January
|
|
dates to be part of the 52nd or 53rd week of the previous year, and for
|
|
late-December dates to be part of the first week of the next year.
|
|
For example, <literal>2005-01-01</literal> is part of the 53rd week of year
|
|
2004, and <literal>2006-01-01</literal> is part of the 52nd week of year
|
|
2005, while <literal>2012-12-31</literal> is part of the first week of 2013.
|
|
It's recommended to use the <literal>isoyear</literal> field together with
|
|
<literal>week</literal> to get consistent results.
|
|
</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</literal>, so subtracting
|
|
<literal>BC</literal> years from <literal>AD</literal> 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>
|
|
|
|
<note>
|
|
<para>
|
|
When the input value is +/-Infinity, <function>extract</function> returns
|
|
+/-Infinity for monotonically-increasing fields (<literal>epoch</literal>,
|
|
<literal>julian</literal>, <literal>year</literal>, <literal>isoyear</literal>,
|
|
<literal>decade</literal>, <literal>century</literal>, and <literal>millennium</literal>).
|
|
For other fields, NULL is returned. <productname>PostgreSQL</productname>
|
|
versions before 9.6 returned zero for all cases of infinite input.
|
|
</para>
|
|
</note>
|
|
|
|
<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> [, <replaceable>time_zone</replaceable> ])
|
|
</synopsis>
|
|
<replaceable>source</replaceable> is a value expression of type
|
|
<type>timestamp</type>, <type>timestamp with time zone</type>,
|
|
or <type>interval</type>.
|
|
(Values of type <type>date</type> and
|
|
<type>time</type> are cast automatically to <type>timestamp</type> or
|
|
<type>interval</type>, respectively.)
|
|
<replaceable>field</replaceable> selects to which precision to
|
|
truncate the input value. The return value is likewise of type
|
|
<type>timestamp</type>, <type>timestamp with time zone</type>,
|
|
or <type>interval</type>,
|
|
and it has 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>
|
|
When the input value is of type <type>timestamp with time zone</type>,
|
|
the truncation is performed with respect to a particular time zone;
|
|
for example, truncation to <literal>day</literal> produces a value that
|
|
is midnight in that zone. By default, truncation is done with respect
|
|
to the current <xref linkend="guc-timezone"/> setting, but the
|
|
optional <replaceable>time_zone</replaceable> argument can be provided
|
|
to specify a different time zone. The time zone name can be specified
|
|
in any of the ways described in <xref linkend="datatype-timezones"/>.
|
|
</para>
|
|
|
|
<para>
|
|
A time zone cannot be specified when processing <type>timestamp without
|
|
time zone</type> or <type>interval</type> inputs. These are always
|
|
taken at face value.
|
|
</para>
|
|
|
|
<para>
|
|
Examples (assuming the local time zone is <literal>America/New_York</literal>):
|
|
<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>
|
|
|
|
SELECT date_trunc('day', TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40+00');
|
|
<lineannotation>Result: </lineannotation><computeroutput>2001-02-16 00:00:00-05</computeroutput>
|
|
|
|
SELECT date_trunc('day', TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40+00', 'Australia/Sydney');
|
|
<lineannotation>Result: </lineannotation><computeroutput>2001-02-16 08:00:00-05</computeroutput>
|
|
|
|
SELECT date_trunc('hour', INTERVAL '3 days 02:47:33');
|
|
<lineannotation>Result: </lineannotation><computeroutput>3 days 02: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> converts time
|
|
stamp <emphasis>without time zone</emphasis> to/from
|
|
time stamp <emphasis>with time zone</emphasis>, and
|
|
<emphasis>time</emphasis> values 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</replaceable></literal>
|
|
</entry>
|
|
<entry><type>timestamp with time zone</type></entry>
|
|
<entry>Treat given time stamp <emphasis>without time zone</emphasis> as located in the specified time zone</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<literal><type>timestamp with time zone</type> AT TIME ZONE <replaceable>zone</replaceable></literal>
|
|
</entry>
|
|
<entry><type>timestamp without time zone</type></entry>
|
|
<entry>Convert given time stamp <emphasis>with time zone</emphasis> 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</replaceable></literal>
|
|
</entry>
|
|
<entry><type>time with time zone</type></entry>
|
|
<entry>Convert given time <emphasis>with time zone</emphasis> to the new time zone</entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
In these expressions, the desired time zone <replaceable>zone</replaceable> can be
|
|
specified either as a text string (e.g., <literal>'America/Los_Angeles'</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>America/Los_Angeles</literal>):
|
|
<screen>
|
|
SELECT TIMESTAMP '2001-02-16 20:38:40' AT TIME ZONE 'America/Denver';
|
|
<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 'America/Denver';
|
|
<lineannotation>Result: </lineannotation><computeroutput>2001-02-16 18:38:40</computeroutput>
|
|
|
|
SELECT TIMESTAMP '2001-02-16 20:38:40-05' AT TIME ZONE 'Asia/Tokyo' AT TIME ZONE 'America/Chicago';
|
|
<lineannotation>Result: </lineannotation><computeroutput>2001-02-16 05:38:40</computeroutput>
|
|
</screen>
|
|
The first example adds a time zone to a value that lacks it, and
|
|
displays the value using the current <varname>TimeZone</varname>
|
|
setting. The second example shifts the time stamp with time zone value
|
|
to the specified time zone, and returns the value without a time zone.
|
|
This allows storage and display of values different from the current
|
|
<varname>TimeZone</varname> setting. The third example converts
|
|
Tokyo time to Chicago time. Converting <emphasis>time</emphasis>
|
|
values to other time zones uses the currently active time zone rules
|
|
since no date is supplied.
|
|
</para>
|
|
|
|
<para>
|
|
The function <literal><function>timezone</function>(<replaceable>zone</replaceable>,
|
|
<replaceable>timestamp</replaceable>)</literal> is equivalent to the SQL-conforming construct
|
|
<literal><replaceable>timestamp</replaceable> AT TIME ZONE
|
|
<replaceable>zone</replaceable></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()</function> is equivalent to
|
|
<function>CURRENT_TIMESTAMP</function>, but is named to clearly reflect
|
|
what it returns.
|
|
<function>statement_timestamp()</function> 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()</function> and <function>transaction_timestamp()</function>
|
|
return the same value during the first command of a transaction, but might
|
|
differ during subsequent commands.
|
|
<function>clock_timestamp()</function> returns the actual current time, and
|
|
therefore its value changes even within a single SQL command.
|
|
<function>timeofday()</function> is a historical
|
|
<productname>PostgreSQL</productname> function. Like
|
|
<function>clock_timestamp()</function>, it returns the actual current time,
|
|
but as a formatted <type>text</type> string rather than a <type>timestamp
|
|
with time zone</type> value.
|
|
<function>now()</function> 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</literal>
|
|
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>pg_sleep_for</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>pg_sleep_until</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>sleep</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>delay</primary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
The following functions are available to delay execution of the server
|
|
process:
|
|
<synopsis>
|
|
pg_sleep(<replaceable>seconds</replaceable>)
|
|
pg_sleep_for(<type>interval</type>)
|
|
pg_sleep_until(<type>timestamp with time zone</type>)
|
|
</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</type>, so fractional-second delays can be specified.
|
|
<function>pg_sleep_for</function> is a convenience function for larger
|
|
sleep times specified as an <type>interval</type>.
|
|
<function>pg_sleep_until</function> is a convenience function for when
|
|
a specific wake-up time is desired.
|
|
For example:
|
|
|
|
<programlisting>
|
|
SELECT pg_sleep(1.5);
|
|
SELECT pg_sleep_for('5 minutes');
|
|
SELECT pg_sleep_until('tomorrow 03:00');
|
|
</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.
|
|
In particular, <function>pg_sleep_until</function> is not guaranteed to
|
|
wake up exactly at the specified time, but it will not wake up any earlier.
|
|
</para>
|
|
</note>
|
|
|
|
<warning>
|
|
<para>
|
|
Make sure that your session does not hold more locks than necessary
|
|
when calling <function>pg_sleep</function> or its variants. 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</function>,
|
|
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</quote> operator, <literal>~=</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>=</literal> operator, but
|
|
<literal>=</literal> compares
|
|
for equal <emphasis>areas</emphasis> only. The other scalar comparison operators
|
|
(<literal><=</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>box '((1,-1),(-1,1))' # box '((1,1),(-2,-2))'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry> <literal>#</literal> </entry>
|
|
<entry>Number of points in path or polygon</entry>
|
|
<entry><literal># path '((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>@></literal> and <literal><@</literal> were respectively
|
|
called <literal>~</literal> and <literal>@</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</replaceable>)</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</replaceable>)</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</type>)</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</type>)</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</type>)</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</type>)</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</replaceable>)</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</type>)</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</type>)</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</type>)</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>
|
|
<row>
|
|
<entry><literal><function>popen(<type>path</type>)</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</type>)</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>)</function></literal></entry>
|
|
<entry><type>box</type></entry>
|
|
<entry>point to empty box</entry>
|
|
<entry><literal>box(point '(0,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><literal><function>bound_box(<type>box</type>, <type>box</type>)</function></literal></entry>
|
|
<entry><type>box</type></entry>
|
|
<entry>boxes to bounding box</entry>
|
|
<entry><literal>bound_box(box '((0,0),(1,1))', box '((3,3),(4,4))')</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><literal><function>line(<type>point</type>, <type>point</type>)</function></literal></entry>
|
|
<entry><type>line</type></entry>
|
|
<entry>points to line</entry>
|
|
<entry><literal>line(point '(-1,0)', point '(1,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>path</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</type>
|
|
as though the point were an array with indexes 0 and 1. For example, if
|
|
<literal>t.p</literal> is a <type>point</type> column then
|
|
<literal>SELECT p[0] FROM t</literal> retrieves the X coordinate and
|
|
<literal>UPDATE t SET p[1] = ...</literal> changes the Y coordinate.
|
|
In the same way, a value of type <type>box</type> or <type>lseg</type> can be treated
|
|
as an array of two <type>point</type> 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>,
|
|
<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 by</entry>
|
|
<entry><literal>inet '192.168.1.5' << inet '192.168.1/24'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry> <literal><<=</literal> </entry>
|
|
<entry>is contained by 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>contains or is contained by</entry>
|
|
<entry><literal>inet '192.168.1/24' && inet '192.168.1.80/28'</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>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>inet_same_family</primary>
|
|
</indexterm>
|
|
<literal><function>inet_same_family(<type>inet</type>, <type>inet</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>are the addresses from the same family?</entry>
|
|
<entry><literal>inet_same_family('192.168.1.5/24', '::1')</literal></entry>
|
|
<entry><literal>false</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>inet_merge</primary>
|
|
</indexterm>
|
|
<literal><function>inet_merge(<type>inet</type>, <type>inet</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>cidr</type></entry>
|
|
<entry>the smallest network which includes both of the given networks</entry>
|
|
<entry><literal>inet_merge('192.168.1.5/24', '192.168.2.5/24')</literal></entry>
|
|
<entry><literal>192.168.0.0/22</literal></entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
Any <type>cidr</type> value can be cast to <type>inet</type> implicitly
|
|
or explicitly; therefore, the functions shown above as operating on
|
|
<type>inet</type> also work on <type>cidr</type> values. (Where there are
|
|
separate functions for <type>inet</type> and <type>cidr</type>, it is because
|
|
the behavior should be different for the two cases.)
|
|
Also, it is permitted to cast an <type>inet</type> value to <type>cidr</type>.
|
|
When this is done, any bits to the right of the netmask are silently zeroed
|
|
to create a valid <type>cidr</type> value.
|
|
In addition,
|
|
you can cast a text value to <type>inet</type> or <type>cidr</type>
|
|
using normal casting syntax: for example,
|
|
<literal>inet(<replaceable>expression</replaceable>)</literal> or
|
|
<literal><replaceable>colname</replaceable>::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, and the bitwise arithmetic operators
|
|
(<literal>~</literal>, <literal>&</literal> and <literal>|</literal>)
|
|
for NOT, AND and OR.
|
|
</para>
|
|
|
|
<para>
|
|
<xref linkend="macaddr8-functions-table"/> shows the functions
|
|
available for use with the <type>macaddr8</type> type. The function
|
|
<literal><function>trunc(<type>macaddr8</type>)</function></literal> returns a MAC
|
|
address with the last 5 bytes set to zero. This can be used to
|
|
associate the remaining prefix with a manufacturer.
|
|
</para>
|
|
|
|
<table id="macaddr8-functions-table">
|
|
<title><type>macaddr8</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>macaddr8</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>macaddr8</type></entry>
|
|
<entry>set last 5 bytes to zero</entry>
|
|
<entry><literal>trunc(macaddr8 '12:34:56:78:90:ab:cd:ef')</literal></entry>
|
|
<entry><literal>12:34:56:00:00:00:00:00</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>macaddr8_set7bit</primary>
|
|
</indexterm>
|
|
<literal><function>macaddr8_set7bit(<type>macaddr8</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>macaddr8</type></entry>
|
|
<entry>set 7th bit to one, also known as modified EUI-64, for inclusion in an IPv6 address</entry>
|
|
<entry><literal>macaddr8_set7bit(macaddr8 '00:34:56:ab:cd:ef')</literal></entry>
|
|
<entry><literal>02:34:56:ff:fe:ab:cd:ef</literal></entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
The <type>macaddr8</type> type also supports the standard relational
|
|
operators (<literal>></literal>, <literal><=</literal>, etc.) for
|
|
ordering, and the bitwise arithmetic operators (<literal>~</literal>,
|
|
<literal>&</literal> and <literal>|</literal>) for NOT, AND and OR.
|
|
</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="5">
|
|
<thead>
|
|
<row>
|
|
<entry>Operator</entry>
|
|
<entry>Return Type</entry>
|
|
<entry>Description</entry>
|
|
<entry>Example</entry>
|
|
<entry>Result</entry>
|
|
</row>
|
|
</thead>
|
|
<tbody>
|
|
<row>
|
|
<entry> <literal>@@</literal> </entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry><type>tsvector</type> matches <type>tsquery</type> ?</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><type>boolean</type></entry>
|
|
<entry>deprecated synonym for <literal>@@</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><type>tsvector</type></entry>
|
|
<entry>concatenate <type>tsvector</type>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><type>tsquery</type></entry>
|
|
<entry>AND <type>tsquery</type>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><type>tsquery</type></entry>
|
|
<entry>OR <type>tsquery</type>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><type>tsquery</type></entry>
|
|
<entry>negate a <type>tsquery</type></entry>
|
|
<entry><literal>!! 'cat'::tsquery</literal></entry>
|
|
<entry><literal>!'cat'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry> <literal><-></literal> </entry>
|
|
<entry><type>tsquery</type></entry>
|
|
<entry><type>tsquery</type> followed by <type>tsquery</type></entry>
|
|
<entry><literal>to_tsquery('fat') <-> to_tsquery('rat')</literal></entry>
|
|
<entry><literal>'fat' <-> 'rat'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry> <literal>@></literal> </entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry><type>tsquery</type> 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>boolean</type></entry>
|
|
<entry><type>tsquery</type> 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</type> 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>, <literal><</literal>, etc) are defined
|
|
for types <type>tsvector</type> and <type>tsquery</type>. 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>array_to_tsvector</primary>
|
|
</indexterm>
|
|
<literal><function>array_to_tsvector(<type>text[]</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>tsvector</type></entry>
|
|
<entry>convert array of lexemes to <type>tsvector</type></entry>
|
|
<entry><literal>array_to_tsvector('{fat,cat,rat}'::text[])</literal></entry>
|
|
<entry><literal>'cat' 'fat' 'rat'</literal></entry>
|
|
</row>
|
|
<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</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>integer</type></entry>
|
|
<entry>number of lexemes in <type>tsvector</type></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</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>integer</type></entry>
|
|
<entry>number of lexemes plus operators in <type>tsquery</type></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</replaceable> <type>regconfig</type> , </optional> <replaceable class="parameter">query</replaceable> <type>text</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>tsquery</type></entry>
|
|
<entry>produce <type>tsquery</type> ignoring punctuation</entry>
|
|
<entry><literal>plainto_tsquery('english', 'The Fat Rats')</literal></entry>
|
|
<entry><literal>'fat' & 'rat'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>phraseto_tsquery</primary>
|
|
</indexterm>
|
|
<literal><function>phraseto_tsquery(<optional> <replaceable class="parameter">config</replaceable> <type>regconfig</type> , </optional> <replaceable class="parameter">query</replaceable> <type>text</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>tsquery</type></entry>
|
|
<entry>produce <type>tsquery</type> that searches for a phrase,
|
|
ignoring punctuation</entry>
|
|
<entry><literal>phraseto_tsquery('english', 'The Fat Rats')</literal></entry>
|
|
<entry><literal>'fat' <-> 'rat'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>websearch_to_tsquery</primary>
|
|
</indexterm>
|
|
<literal><function>websearch_to_tsquery(<optional> <replaceable class="parameter">config</replaceable> <type>regconfig</type> , </optional> <replaceable class="parameter">query</replaceable> <type>text</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>tsquery</type></entry>
|
|
<entry>produce <type>tsquery</type> from a web search style query</entry>
|
|
<entry><literal>websearch_to_tsquery('english', '"fat rat" or rat')</literal></entry>
|
|
<entry><literal>'fat' <-> 'rat' | 'rat'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>querytree</primary>
|
|
</indexterm>
|
|
<literal><function>querytree(<replaceable class="parameter">query</replaceable> <type>tsquery</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>get indexable part of a <type>tsquery</type></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(<replaceable class="parameter">vector</replaceable> <type>tsvector</type>, <replaceable class="parameter">weight</replaceable> <type>"char"</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>tsvector</type></entry>
|
|
<entry>assign <replaceable class="parameter">weight</replaceable> to each element of <replaceable class="parameter">vector</replaceable></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>setweight</primary>
|
|
<secondary>setweight for specific lexeme(s)</secondary>
|
|
</indexterm>
|
|
<literal><function>setweight(<replaceable class="parameter">vector</replaceable> <type>tsvector</type>, <replaceable class="parameter">weight</replaceable> <type>"char"</type>, <replaceable class="parameter">lexemes</replaceable> <type>text[]</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>tsvector</type></entry>
|
|
<entry>assign <replaceable class="parameter">weight</replaceable> to elements of <replaceable class="parameter">vector</replaceable> that are listed in <replaceable class="parameter">lexemes</replaceable></entry>
|
|
<entry><literal>setweight('fat:2,4 cat:3 rat:5B'::tsvector, 'A', '{cat,rat}')</literal></entry>
|
|
<entry><literal>'cat':3A 'fat':2,4 'rat':5A</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>strip</primary>
|
|
</indexterm>
|
|
<literal><function>strip(<type>tsvector</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>tsvector</type></entry>
|
|
<entry>remove positions and weights from <type>tsvector</type></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</replaceable> <type>regconfig</type> , </optional> <replaceable class="parameter">query</replaceable> <type>text</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>tsquery</type></entry>
|
|
<entry>normalize words and convert to <type>tsquery</type></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</replaceable> <type>regconfig</type> , </optional> <replaceable class="parameter">document</replaceable> <type>text</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>tsvector</type></entry>
|
|
<entry>reduce document text to <type>tsvector</type></entry>
|
|
<entry><literal>to_tsvector('english', 'The Fat Rats')</literal></entry>
|
|
<entry><literal>'fat':2 'rat':3</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>to_tsvector(<optional> <replaceable class="parameter">config</replaceable> <type>regconfig</type> , </optional> <replaceable class="parameter">document</replaceable> <type>json(b)</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>tsvector</type></entry>
|
|
<entry>
|
|
reduce each string value in the document to a <type>tsvector</type>, and then
|
|
concatenate those in document order to produce a single <type>tsvector</type>
|
|
</entry>
|
|
<entry><literal>to_tsvector('english', '{"a": "The Fat Rats"}'::json)</literal></entry>
|
|
<entry><literal>'fat':2 'rat':3</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>json(b)_to_tsvector(<optional> <replaceable class="parameter">config</replaceable> <type>regconfig</type>,
|
|
</optional> <replaceable class="parameter">document</replaceable> <type>json(b)</type>,
|
|
<replaceable class="parameter">filter</replaceable> <type>json(b)</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>tsvector</type></entry>
|
|
<entry>
|
|
reduce each value in the document, specified by <replaceable class="parameter">filter</replaceable> to a <type>tsvector</type>,
|
|
and then concatenate those in document order to produce a single <type>tsvector</type>.
|
|
<replaceable class="parameter">filter</replaceable> is a <type>jsonb</type> array, that enumerates what kind of elements need to be included
|
|
into the resulting <type>tsvector</type>. Possible values for <replaceable class="parameter">filter</replaceable> are
|
|
<literal>"string"</literal> (to include all string values), <literal>"numeric"</literal> (to include all numeric values in the string format),
|
|
<literal>"boolean"</literal> (to include all Boolean values in the string format <literal>"true"</literal>/<literal>"false"</literal>),
|
|
<literal>"key"</literal> (to include all keys) or <literal>"all"</literal> (to include all above). These values
|
|
can be combined together to include, e.g. all string and numeric values.
|
|
</entry>
|
|
<entry><literal>json_to_tsvector('english', '{"a": "The Fat Rats", "b": 123}'::json, '["string", "numeric"]')</literal></entry>
|
|
<entry><literal>'123':5 'fat':2 'rat':3</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>ts_delete</primary>
|
|
</indexterm>
|
|
<literal><function>ts_delete(<replaceable class="parameter">vector</replaceable> <type>tsvector</type>, <replaceable class="parameter">lexeme</replaceable> <type>text</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>tsvector</type></entry>
|
|
<entry>remove given <replaceable class="parameter">lexeme</replaceable> from <replaceable class="parameter">vector</replaceable></entry>
|
|
<entry><literal>ts_delete('fat:2,4 cat:3 rat:5A'::tsvector, 'fat')</literal></entry>
|
|
<entry><literal>'cat':3 'rat':5A</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<!-- previous indexterm entry covers this too -->
|
|
<literal><function>ts_delete(<replaceable class="parameter">vector</replaceable> <type>tsvector</type>, <replaceable class="parameter">lexemes</replaceable> <type>text[]</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>tsvector</type></entry>
|
|
<entry>remove any occurrence of lexemes in <replaceable class="parameter">lexemes</replaceable> from <replaceable class="parameter">vector</replaceable></entry>
|
|
<entry><literal>ts_delete('fat:2,4 cat:3 rat:5A'::tsvector, ARRAY['fat','rat'])</literal></entry>
|
|
<entry><literal>'cat':3</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>ts_filter</primary>
|
|
</indexterm>
|
|
<literal><function>ts_filter(<replaceable class="parameter">vector</replaceable> <type>tsvector</type>, <replaceable class="parameter">weights</replaceable> <type>"char"[]</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>tsvector</type></entry>
|
|
<entry>select only elements with given <replaceable class="parameter">weights</replaceable> from <replaceable class="parameter">vector</replaceable></entry>
|
|
<entry><literal>ts_filter('fat:2,4 cat:3b rat:5A'::tsvector, '{a,b}')</literal></entry>
|
|
<entry><literal>'cat':3B 'rat':5A</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>ts_headline</primary>
|
|
</indexterm>
|
|
<literal><function>ts_headline(<optional> <replaceable class="parameter">config</replaceable> <type>regconfig</type>, </optional> <replaceable class="parameter">document</replaceable> <type>text</type>, <replaceable class="parameter">query</replaceable> <type>tsquery</type> <optional>, <replaceable class="parameter">options</replaceable> <type>text</type> </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>
|
|
<literal><function>ts_headline(<optional> <replaceable class="parameter">config</replaceable> <type>regconfig</type>, </optional> <replaceable class="parameter">document</replaceable> <type>json(b)</type>, <replaceable class="parameter">query</replaceable> <type>tsquery</type> <optional>, <replaceable class="parameter">options</replaceable> <type>text</type> </optional>)</function></literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>display a query match</entry>
|
|
<entry><literal>ts_headline('{"a":"x y z"}'::json, 'z'::tsquery)</literal></entry>
|
|
<entry><literal>{"a":"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[]</type>, </optional> <replaceable class="parameter">vector</replaceable> <type>tsvector</type>, <replaceable class="parameter">query</replaceable> <type>tsquery</type> <optional>, <replaceable class="parameter">normalization</replaceable> <type>integer</type> </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[]</type>, </optional> <replaceable class="parameter">vector</replaceable> <type>tsvector</type>, <replaceable class="parameter">query</replaceable> <type>tsquery</type> <optional>, <replaceable class="parameter">normalization</replaceable> <type>integer</type> </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</type>, <replaceable class="parameter">target</replaceable> <type>tsquery</type>, <replaceable class="parameter">substitute</replaceable> <type>tsquery</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>tsquery</type></entry>
|
|
<entry>replace <replaceable>target</replaceable> with <replaceable>substitute</replaceable>
|
|
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</type>, <replaceable class="parameter">select</replaceable> <type>text</type>)</function></literal></entry>
|
|
<entry><type>tsquery</type></entry>
|
|
<entry>replace using targets and substitutes from a <command>SELECT</command> 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>tsquery_phrase</primary>
|
|
</indexterm>
|
|
<literal><function>tsquery_phrase(<replaceable class="parameter">query1</replaceable> <type>tsquery</type>, <replaceable class="parameter">query2</replaceable> <type>tsquery</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>tsquery</type></entry>
|
|
<entry>make query that searches for <replaceable>query1</replaceable> followed
|
|
by <replaceable>query2</replaceable> (same as <literal><-></literal>
|
|
operator)</entry>
|
|
<entry><literal>tsquery_phrase(to_tsquery('fat'), to_tsquery('cat'))</literal></entry>
|
|
<entry><literal>'fat' <-> 'cat'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>tsquery_phrase(<replaceable class="parameter">query1</replaceable> <type>tsquery</type>, <replaceable class="parameter">query2</replaceable> <type>tsquery</type>, <replaceable class="parameter">distance</replaceable> <type>integer</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>tsquery</type></entry>
|
|
<entry>make query that searches for <replaceable>query1</replaceable> followed by
|
|
<replaceable>query2</replaceable> at distance <replaceable>distance</replaceable></entry>
|
|
<entry><literal>tsquery_phrase(to_tsquery('fat'), to_tsquery('cat'), 10)</literal></entry>
|
|
<entry><literal>'fat' <10> 'cat'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>tsvector_to_array</primary>
|
|
</indexterm>
|
|
<literal><function>tsvector_to_array(<type>tsvector</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>text[]</type></entry>
|
|
<entry>convert <type>tsvector</type> to array of lexemes</entry>
|
|
<entry><literal>tsvector_to_array('fat:2,4 cat:3 rat:5A'::tsvector)</literal></entry>
|
|
<entry><literal>{cat,fat,rat}</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</type> 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</type> column update</entry>
|
|
<entry><literal>CREATE TRIGGER ... tsvector_update_trigger_column(tsvcol, configcol, title, body)</literal></entry>
|
|
<entry><literal></literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>unnest</primary>
|
|
<secondary>for tsvector</secondary>
|
|
</indexterm>
|
|
<literal><function>unnest(<type>tsvector</type>, OUT <replaceable class="parameter">lexeme</replaceable> <type>text</type>, OUT <replaceable class="parameter">positions</replaceable> <type>smallint[]</type>, OUT <replaceable class="parameter">weights</replaceable> <type>text</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>setof record</type></entry>
|
|
<entry>expand a <type>tsvector</type> to a set of rows</entry>
|
|
<entry><literal>unnest('fat:2,4 cat:3 rat:5A'::tsvector)</literal></entry>
|
|
<entry><literal>(cat,{3},{D}) ...</literal></entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<note>
|
|
<para>
|
|
All the text search functions that accept an optional <type>regconfig</type>
|
|
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</type>, </optional> <replaceable class="parameter">document</replaceable> <type>text</type>, OUT <replaceable class="parameter">alias</replaceable> <type>text</type>, OUT <replaceable class="parameter">description</replaceable> <type>text</type>, OUT <replaceable class="parameter">token</replaceable> <type>text</type>, OUT <replaceable class="parameter">dictionaries</replaceable> <type>regdictionary[]</type>, OUT <replaceable class="parameter">dictionary</replaceable> <type>regdictionary</type>, OUT <replaceable class="parameter">lexemes</replaceable> <type>text[]</type>)</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</type>, <replaceable class="parameter">token</replaceable> <type>text</type>)</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</type>, <replaceable class="parameter">document</replaceable> <type>text</type>, OUT <replaceable class="parameter">tokid</replaceable> <type>integer</type>, OUT <replaceable class="parameter">token</replaceable> <type>text</type>)</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</type>, <replaceable class="parameter">document</replaceable> <type>text</type>, OUT <replaceable class="parameter">tokid</replaceable> <type>integer</type>, OUT <replaceable class="parameter">token</replaceable> <type>text</type>)</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</replaceable> <type>text</type>, OUT <replaceable class="parameter">tokid</replaceable> <type>integer</type>, OUT <replaceable class="parameter">alias</replaceable> <type>text</type>, OUT <replaceable class="parameter">description</replaceable> <type>text</type>)</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</replaceable> <type>oid</type>, OUT <replaceable class="parameter">tokid</replaceable> <type>integer</type>, OUT <replaceable class="parameter">alias</replaceable> <type>text</type>, OUT <replaceable class="parameter">description</replaceable> <type>text</type>)</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</type>, <optional> <replaceable class="parameter">weights</replaceable> <type>text</type>, </optional> OUT <replaceable class="parameter">word</replaceable> <type>text</type>, OUT <replaceable class="parameter">ndoc</replaceable> <type>integer</type>, OUT <replaceable class="parameter">nentry</replaceable> <type>integer</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>setof record</type></entry>
|
|
<entry>get statistics of a <type>tsvector</type> 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>
|
|
|
|
<indexterm>
|
|
<primary>XML Functions</primary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
The functions and function-like expressions described in this
|
|
section operate on values of type <type>xml</type>. See <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 documented there, not in this section.
|
|
</para>
|
|
|
|
<para>
|
|
Use of most of these functions
|
|
requires <productname>PostgreSQL</productname> to have been built
|
|
with <command>configure --with-libxml</command>.
|
|
</para>
|
|
|
|
<sect2 id="functions-producing-xml">
|
|
<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
|
|
PostgreSQL mappings with those specified in SQL:2006 and later,
|
|
as discussed in <xref linkend="functions-xml-limits-casts"/>.
|
|
</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</literal>
|
|
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 id="functions-xml-predicates">
|
|
<title>XML Predicates</title>
|
|
|
|
<para>
|
|
The expressions described in this section check properties
|
|
of <type>xml</type> values.
|
|
</para>
|
|
|
|
<sect3>
|
|
<title><literal>IS DOCUMENT</literal></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><literal>IS NOT DOCUMENT</literal></title>
|
|
|
|
<indexterm>
|
|
<primary>IS NOT DOCUMENT</primary>
|
|
</indexterm>
|
|
|
|
<synopsis>
|
|
<replaceable>xml</replaceable> IS NOT DOCUMENT
|
|
</synopsis>
|
|
|
|
<para>
|
|
The expression <literal>IS NOT DOCUMENT</literal> returns false if the
|
|
argument XML value is a proper XML document, true if it is not (that is,
|
|
it is a content fragment), or null if the argument is null.
|
|
</para>
|
|
</sect3>
|
|
|
|
<sect3 id="xml-exists">
|
|
<title><literal>XMLEXISTS</literal></title>
|
|
|
|
<indexterm>
|
|
<primary>XMLEXISTS</primary>
|
|
</indexterm>
|
|
|
|
<synopsis>
|
|
<function>XMLEXISTS</function>(<replaceable>text</replaceable> PASSING <optional>BY { REF | VALUE }</optional> <replaceable>xml</replaceable> <optional>BY { REF | VALUE }</optional>)
|
|
</synopsis>
|
|
|
|
<para>
|
|
The function <function>xmlexists</function> evaluates an XPath 1.0
|
|
expression (the first argument), with the passed XML value as its context
|
|
item. The function returns false if the result of that evaluation
|
|
yields an empty node-set, true if it yields any other value. The
|
|
function returns null if any argument is null. A nonnull value
|
|
passed as the context item must be an XML document, not a content
|
|
fragment or any non-XML value.
|
|
</para>
|
|
|
|
<para>
|
|
Example:
|
|
<screen><![CDATA[
|
|
SELECT xmlexists('//town[text() = ''Toronto'']' PASSING BY VALUE '<towns><town>Toronto</town><town>Ottawa</town></towns>');
|
|
|
|
xmlexists
|
|
------------
|
|
t
|
|
(1 row)
|
|
]]></screen>
|
|
</para>
|
|
|
|
<para>
|
|
The <literal>BY REF</literal> and <literal>BY VALUE</literal> clauses
|
|
are accepted in <productname>PostgreSQL</productname>, but are ignored,
|
|
as discussed in <xref linkend="functions-xml-limits-postgresql"/>.
|
|
In the SQL standard, the <function>xmlexists</function> function
|
|
evaluates an expression in the XML Query language,
|
|
but <productname>PostgreSQL</productname> allows only an XPath 1.0
|
|
expression, as discussed in
|
|
<xref linkend="functions-xml-limits-xpath1"/>.
|
|
</para>
|
|
</sect3>
|
|
|
|
<sect3 id="xml-is-well-formed">
|
|
<title><literal>xml_is_well_formed</literal></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</type> 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</literal>, or the latter if it is set to
|
|
<literal>CONTENT</literal>. This means that
|
|
<function>xml_is_well_formed</function> is useful for seeing whether
|
|
a simple cast to type <type>xml</type> will succeed, whereas the other two
|
|
functions are useful for seeing whether the corresponding variants of
|
|
<function>XMLPARSE</function> 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>
|
|
|
|
<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, and the <function>XMLTABLE</function>
|
|
table function.
|
|
</para>
|
|
|
|
<sect3 id="functions-xml-processing-xpath">
|
|
<title><literal>xpath</literal></title>
|
|
|
|
<indexterm>
|
|
<primary>XPath</primary>
|
|
</indexterm>
|
|
|
|
<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 1.0
|
|
expression <replaceable>xpath</replaceable> (a <type>text</type> 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.
|
|
If the XPath expression returns a scalar value rather than a node-set,
|
|
a single-element array is returned.
|
|
</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</type> 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</emphasis>).
|
|
</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>
|
|
</sect3>
|
|
|
|
<sect3 id="functions-xml-processing-xpath-exists">
|
|
<title><literal>xpath_exists</literal></title>
|
|
|
|
<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 1.0 expression, this function
|
|
returns a Boolean indicating whether the query was satisfied or not
|
|
(specifically, whether it produced any value other than an empty node-set).
|
|
This function is equivalent to the <literal>XMLEXISTS</literal> 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>
|
|
</sect3>
|
|
|
|
<sect3 id="functions-xml-processing-xmltable">
|
|
<title><literal>xmltable</literal></title>
|
|
|
|
<indexterm>
|
|
<primary>xmltable</primary>
|
|
</indexterm>
|
|
|
|
<indexterm zone="functions-xml-processing-xmltable">
|
|
<primary>table function</primary>
|
|
<secondary>XMLTABLE</secondary>
|
|
</indexterm>
|
|
|
|
<synopsis>
|
|
<function>xmltable</function>( <optional>XMLNAMESPACES(<replaceable>namespace uri</replaceable> AS <replaceable>namespace name</replaceable><optional>, ...</optional>), </optional>
|
|
<replaceable>row_expression</replaceable> PASSING <optional>BY { REF | VALUE }</optional> <replaceable>document_expression</replaceable> <optional>BY { REF | VALUE }</optional>
|
|
COLUMNS <replaceable>name</replaceable> { <replaceable>type</replaceable> <optional>PATH <replaceable>column_expression</replaceable></optional> <optional>DEFAULT <replaceable>default_expression</replaceable></optional> <optional>NOT NULL | NULL</optional>
|
|
| FOR ORDINALITY }
|
|
<optional>, ...</optional>
|
|
)
|
|
</synopsis>
|
|
|
|
<para>
|
|
The <function>xmltable</function> function produces a table based
|
|
on the given XML value, an XPath filter to extract rows, and a
|
|
set of column definitions.
|
|
</para>
|
|
|
|
<para>
|
|
The optional <literal>XMLNAMESPACES</literal> clause is a comma-separated
|
|
list of namespaces. It specifies the XML namespaces used in
|
|
the document and their aliases. A default namespace specification
|
|
is not currently supported.
|
|
</para>
|
|
|
|
<para>
|
|
The required <replaceable>row_expression</replaceable> argument is
|
|
an XPath 1.0 expression that is evaluated, passing the
|
|
<replaceable>document_expression</replaceable> as its context item, to
|
|
obtain a set of XML nodes. These nodes are what
|
|
<function>xmltable</function> transforms into output rows. No rows
|
|
will be produced if the <replaceable>document_expression</replaceable>
|
|
is null, nor if the <replaceable>row_expression</replaceable> produces
|
|
an empty node-set or any value other than a node-set.
|
|
</para>
|
|
|
|
<para>
|
|
<replaceable>document_expression</replaceable> provides the context
|
|
item for the <replaceable>row_expression</replaceable>. It must be a
|
|
well-formed XML document; fragments/forests are not accepted.
|
|
The <literal>BY REF</literal> and <literal>BY VALUE</literal> clauses
|
|
are accepted but ignored, as discussed in
|
|
<xref linkend="functions-xml-limits-postgresql"/>.
|
|
In the SQL standard, the <function>xmltable</function> function
|
|
evaluates expressions in the XML Query language,
|
|
but <productname>PostgreSQL</productname> allows only XPath 1.0
|
|
expressions, as discussed in
|
|
<xref linkend="functions-xml-limits-xpath1"/>.
|
|
</para>
|
|
|
|
<para>
|
|
The mandatory <literal>COLUMNS</literal> clause specifies the list
|
|
of columns in the output table.
|
|
Each entry describes a single column.
|
|
See the syntax summary above for the format.
|
|
The column name and type are required; the path, default and
|
|
nullability clauses are optional.
|
|
</para>
|
|
|
|
<para>
|
|
A column marked <literal>FOR ORDINALITY</literal> will be populated
|
|
with row numbers, starting with 1, in the order of nodes retrieved from
|
|
the <replaceable>row_expression</replaceable>'s result node-set.
|
|
At most one column may be marked <literal>FOR ORDINALITY</literal>.
|
|
</para>
|
|
|
|
<note>
|
|
<para>
|
|
XPath 1.0 does not specify an order for nodes in a node-set, so code
|
|
that relies on a particular order of the results will be
|
|
implementation-dependent. Details can be found in
|
|
<xref linkend="xml-xpath-1-specifics"/>.
|
|
</para>
|
|
</note>
|
|
|
|
<para>
|
|
The <replaceable>column_expression</replaceable> for a column is an
|
|
XPath 1.0 expression that is evaluated for each row, with the current
|
|
node from the <replaceable>row_expression</replaceable> result as its
|
|
context item, to find the value of the column. If
|
|
no <replaceable>column_expression</replaceable> is given, then the
|
|
column name is used as an implicit path.
|
|
</para>
|
|
|
|
<para>
|
|
If a column's XPath expression returns a non-XML value (limited to
|
|
string, boolean, or double in XPath 1.0) and the column has a
|
|
PostgreSQL type other than <type>xml</type>, the column will be set
|
|
as if by assigning the value's string representation to the PostgreSQL
|
|
type. (If the value is a boolean, its string representation is taken
|
|
to be <literal>1</literal> or <literal>0</literal> if the output
|
|
column's type category is numeric, otherwise <literal>true</literal> or
|
|
<literal>false</literal>.)
|
|
</para>
|
|
|
|
<para>
|
|
If a column's XPath expression returns a non-empty set of XML nodes
|
|
and the column's PostgreSQL type is <type>xml</type>, the column will
|
|
be assigned the expression result exactly, if it is of document or
|
|
content form.
|
|
<footnote>
|
|
<para>
|
|
A result containing more than one element node at the top level, or
|
|
non-whitespace text outside of an element, is an example of content form.
|
|
An XPath result can be of neither form, for example if it returns an
|
|
attribute node selected from the element that contains it. Such a result
|
|
will be put into content form with each such disallowed node replaced by
|
|
its string value, as defined for the XPath 1.0
|
|
<function>string</function> function.
|
|
</para>
|
|
</footnote>
|
|
</para>
|
|
|
|
<para>
|
|
A non-XML result assigned to an <type>xml</type> output column produces
|
|
content, a single text node with the string value of the result.
|
|
An XML result assigned to a column of any other type may not have more than
|
|
one node, or an error is raised. If there is exactly one node, the column
|
|
will be set as if by assigning the node's string
|
|
value (as defined for the XPath 1.0 <function>string</function> function)
|
|
to the PostgreSQL type.
|
|
</para>
|
|
|
|
<para>
|
|
The string value of an XML element is the concatenation, in document order,
|
|
of all text nodes contained in that element and its descendants. The string
|
|
value of an element with no descendant text nodes is an
|
|
empty string (not <literal>NULL</literal>).
|
|
Any <literal>xsi:nil</literal> attributes are ignored.
|
|
Note that the whitespace-only <literal>text()</literal> node between two non-text
|
|
elements is preserved, and that leading whitespace on a <literal>text()</literal>
|
|
node is not flattened.
|
|
The XPath 1.0 <function>string</function> function may be consulted for the
|
|
rules defining the string value of other XML node types and non-XML values.
|
|
</para>
|
|
|
|
<para>
|
|
The conversion rules presented here are not exactly those of the SQL
|
|
standard, as discussed in <xref linkend="functions-xml-limits-casts"/>.
|
|
</para>
|
|
|
|
<para>
|
|
If the path expression returns an empty node-set
|
|
(typically, when it does not match)
|
|
for a given row, the column will be set to <literal>NULL</literal>, unless
|
|
a <replaceable>default_expression</replaceable> is specified; then the
|
|
value resulting from evaluating that expression is used.
|
|
</para>
|
|
|
|
<para>
|
|
Columns may be marked <literal>NOT NULL</literal>. If the
|
|
<replaceable>column_expression</replaceable> for a <literal>NOT NULL</literal> column
|
|
does not match anything and there is no <literal>DEFAULT</literal> or the
|
|
<replaceable>default_expression</replaceable> also evaluates to null, an error
|
|
is reported.
|
|
</para>
|
|
|
|
<para>
|
|
A <replaceable>default_expression</replaceable>, rather than being
|
|
evaluated immediately when <function>xmltable</function> is called,
|
|
is evaluated each time a default is needed for the column.
|
|
If the expression qualifies as stable or immutable, the repeat
|
|
evaluation may be skipped.
|
|
This means that you can usefully use volatile functions like
|
|
<function>nextval</function> in
|
|
<replaceable>default_expression</replaceable>.
|
|
</para>
|
|
|
|
<para>
|
|
Examples:
|
|
<screen><![CDATA[
|
|
CREATE TABLE xmldata AS SELECT
|
|
xml $$
|
|
<ROWS>
|
|
<ROW id="1">
|
|
<COUNTRY_ID>AU</COUNTRY_ID>
|
|
<COUNTRY_NAME>Australia</COUNTRY_NAME>
|
|
</ROW>
|
|
<ROW id="5">
|
|
<COUNTRY_ID>JP</COUNTRY_ID>
|
|
<COUNTRY_NAME>Japan</COUNTRY_NAME>
|
|
<PREMIER_NAME>Shinzo Abe</PREMIER_NAME>
|
|
<SIZE unit="sq_mi">145935</SIZE>
|
|
</ROW>
|
|
<ROW id="6">
|
|
<COUNTRY_ID>SG</COUNTRY_ID>
|
|
<COUNTRY_NAME>Singapore</COUNTRY_NAME>
|
|
<SIZE unit="sq_km">697</SIZE>
|
|
</ROW>
|
|
</ROWS>
|
|
$$ AS data;
|
|
|
|
SELECT xmltable.*
|
|
FROM xmldata,
|
|
XMLTABLE('//ROWS/ROW'
|
|
PASSING data
|
|
COLUMNS id int PATH '@id',
|
|
ordinality FOR ORDINALITY,
|
|
"COUNTRY_NAME" text,
|
|
country_id text PATH 'COUNTRY_ID',
|
|
size_sq_km float PATH 'SIZE[@unit = "sq_km"]',
|
|
size_other text PATH
|
|
'concat(SIZE[@unit!="sq_km"], " ", SIZE[@unit!="sq_km"]/@unit)',
|
|
premier_name text PATH 'PREMIER_NAME' DEFAULT 'not specified') ;
|
|
|
|
id | ordinality | COUNTRY_NAME | country_id | size_sq_km | size_other | premier_name
|
|
----+------------+--------------+------------+------------+--------------+---------------
|
|
1 | 1 | Australia | AU | | | not specified
|
|
5 | 2 | Japan | JP | | 145935 sq_mi | Shinzo Abe
|
|
6 | 3 | Singapore | SG | 697 | | not specified
|
|
]]></screen>
|
|
|
|
The following example shows concatenation of multiple text() nodes,
|
|
usage of the column name as XPath filter, and the treatment of whitespace,
|
|
XML comments and processing instructions:
|
|
|
|
<screen><![CDATA[
|
|
CREATE TABLE xmlelements AS SELECT
|
|
xml $$
|
|
<root>
|
|
<element> Hello<!-- xyxxz -->2a2<?aaaaa?> <!--x--> bbb<x>xxx</x>CC </element>
|
|
</root>
|
|
$$ AS data;
|
|
|
|
SELECT xmltable.*
|
|
FROM xmlelements, XMLTABLE('/root' PASSING data COLUMNS element text);
|
|
element
|
|
-------------------------
|
|
Hello2a2 bbbxxxCC
|
|
]]></screen>
|
|
</para>
|
|
|
|
<para>
|
|
The following example illustrates how
|
|
the <literal>XMLNAMESPACES</literal> clause can be used to specify
|
|
a list of namespaces
|
|
used in the XML document as well as in the XPath expressions:
|
|
|
|
<screen><![CDATA[
|
|
WITH xmldata(data) AS (VALUES ('
|
|
<example xmlns="http://example.com/myns" xmlns:B="http://example.com/b">
|
|
<item foo="1" B:bar="2"/>
|
|
<item foo="3" B:bar="4"/>
|
|
<item foo="4" B:bar="5"/>
|
|
</example>'::xml)
|
|
)
|
|
SELECT xmltable.*
|
|
FROM XMLTABLE(XMLNAMESPACES('http://example.com/myns' AS x,
|
|
'http://example.com/b' AS "B"),
|
|
'/x:example/x:item'
|
|
PASSING (SELECT data FROM xmldata)
|
|
COLUMNS foo int PATH '@foo',
|
|
bar int PATH '@B:bar');
|
|
foo | bar
|
|
-----+-----
|
|
1 | 2
|
|
3 | 4
|
|
4 | 5
|
|
(3 rows)
|
|
]]></screen>
|
|
</para>
|
|
</sect3>
|
|
</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-json">
|
|
<title>JSON Functions and Operators</title>
|
|
|
|
<indexterm zone="functions-json">
|
|
<primary>JSON</primary>
|
|
<secondary>functions and operators</secondary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
This section describes:
|
|
|
|
<itemizedlist>
|
|
<listitem>
|
|
<para>
|
|
functions and operators for processing and creating JSON data
|
|
</para>
|
|
</listitem>
|
|
<listitem>
|
|
<para>
|
|
the SQL/JSON path language
|
|
</para>
|
|
</listitem>
|
|
</itemizedlist>
|
|
</para>
|
|
|
|
<para>
|
|
To learn more about the SQL/JSON standard, see
|
|
<xref linkend="sqltr-19075-6"/>. For details on JSON types
|
|
supported in <productname>PostgreSQL</productname>,
|
|
see <xref linkend="datatype-json"/>.
|
|
</para>
|
|
|
|
<sect2 id="functions-json-processing">
|
|
<title>Processing and Creating JSON Data</title>
|
|
|
|
<para>
|
|
<xref linkend="functions-json-op-table"/> shows the operators that
|
|
are available for use with JSON data types (see <xref
|
|
linkend="datatype-json"/>).
|
|
</para>
|
|
|
|
<table id="functions-json-op-table">
|
|
<title><type>json</type> and <type>jsonb</type> Operators</title>
|
|
<tgroup cols="6">
|
|
<thead>
|
|
<row>
|
|
<entry>Operator</entry>
|
|
<entry>Right Operand Type</entry>
|
|
<entry>Return type</entry>
|
|
<entry>Description</entry>
|
|
<entry>Example</entry>
|
|
<entry>Example Result</entry>
|
|
</row>
|
|
</thead>
|
|
<tbody>
|
|
<row>
|
|
<entry><literal>-></literal></entry>
|
|
<entry><type>int</type></entry>
|
|
<entry><type>json</type> or <type>jsonb</type></entry>
|
|
<entry>Get JSON array element (indexed from zero, negative
|
|
integers count from the end)</entry>
|
|
<entry><literal>'[{"a":"foo"},{"b":"bar"},{"c":"baz"}]'::json->2</literal></entry>
|
|
<entry><literal>{"c":"baz"}</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>-></literal></entry>
|
|
<entry><type>text</type></entry>
|
|
<entry><type>json</type> or <type>jsonb</type></entry>
|
|
<entry>Get JSON object field by key</entry>
|
|
<entry><literal>'{"a": {"b":"foo"}}'::json->'a'</literal></entry>
|
|
<entry><literal>{"b":"foo"}</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>->></literal></entry>
|
|
<entry><type>int</type></entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>Get JSON array element as <type>text</type></entry>
|
|
<entry><literal>'[1,2,3]'::json->>2</literal></entry>
|
|
<entry><literal>3</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>->></literal></entry>
|
|
<entry><type>text</type></entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>Get JSON object field as <type>text</type></entry>
|
|
<entry><literal>'{"a":1,"b":2}'::json->>'b'</literal></entry>
|
|
<entry><literal>2</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>#></literal></entry>
|
|
<entry><type>text[]</type></entry>
|
|
<entry><type>json</type> or <type>jsonb</type></entry>
|
|
<entry>Get JSON object at the specified path</entry>
|
|
<entry><literal>'{"a": {"b":{"c": "foo"}}}'::json#>'{a,b}'</literal></entry>
|
|
<entry><literal>{"c": "foo"}</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>#>></literal></entry>
|
|
<entry><type>text[]</type></entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>Get JSON object at the specified path as <type>text</type></entry>
|
|
<entry><literal>'{"a":[1,2,3],"b":[4,5,6]}'::json#>>'{a,2}'</literal></entry>
|
|
<entry><literal>3</literal></entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<note>
|
|
<para>
|
|
There are parallel variants of these operators for both the
|
|
<type>json</type> and <type>jsonb</type> types.
|
|
The field/element/path extraction operators
|
|
return the same type as their left-hand input (either <type>json</type>
|
|
or <type>jsonb</type>), except for those specified as
|
|
returning <type>text</type>, which coerce the value to text.
|
|
The field/element/path extraction operators return NULL, rather than
|
|
failing, if the JSON input does not have the right structure to match
|
|
the request; for example if no such element exists. The
|
|
field/element/path extraction operators that accept integer JSON
|
|
array subscripts all support negative subscripting from the end of
|
|
arrays.
|
|
</para>
|
|
</note>
|
|
<para>
|
|
The standard comparison operators shown in <xref
|
|
linkend="functions-comparison-op-table"/> are available for
|
|
<type>jsonb</type>, but not for <type>json</type>. They follow the
|
|
ordering rules for B-tree operations outlined at <xref
|
|
linkend="json-indexing"/>.
|
|
</para>
|
|
<para>
|
|
Some further operators also exist only for <type>jsonb</type>, as shown
|
|
in <xref linkend="functions-jsonb-op-table"/>.
|
|
Many of these operators can be indexed by
|
|
<type>jsonb</type> operator classes. For a full description of
|
|
<type>jsonb</type> containment and existence semantics, see <xref
|
|
linkend="json-containment"/>. <xref linkend="json-indexing"/>
|
|
describes how these operators can be used to effectively index
|
|
<type>jsonb</type> data.
|
|
</para>
|
|
<table id="functions-jsonb-op-table">
|
|
<title>Additional <type>jsonb</type> Operators</title>
|
|
<tgroup cols="4">
|
|
<thead>
|
|
<row>
|
|
<entry>Operator</entry>
|
|
<entry>Right Operand Type</entry>
|
|
<entry>Description</entry>
|
|
<entry>Example</entry>
|
|
</row>
|
|
</thead>
|
|
<tbody>
|
|
<row>
|
|
<entry><literal>@></literal></entry>
|
|
<entry><type>jsonb</type></entry>
|
|
<entry>Does the left JSON value contain the right JSON
|
|
path/value entries at the top level?</entry>
|
|
<entry><literal>'{"a":1, "b":2}'::jsonb @> '{"b":2}'::jsonb</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><@</literal></entry>
|
|
<entry><type>jsonb</type></entry>
|
|
<entry>Are the left JSON path/value entries contained at the top level within
|
|
the right JSON value?</entry>
|
|
<entry><literal>'{"b":2}'::jsonb <@ '{"a":1, "b":2}'::jsonb</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>?</literal></entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>Does the <emphasis>string</emphasis> exist as a top-level
|
|
key within the JSON value?</entry>
|
|
<entry><literal>'{"a":1, "b":2}'::jsonb ? 'b'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>?|</literal></entry>
|
|
<entry><type>text[]</type></entry>
|
|
<entry>Do any of these array <emphasis>strings</emphasis>
|
|
exist as top-level keys?</entry>
|
|
<entry><literal>'{"a":1, "b":2, "c":3}'::jsonb ?| array['b', 'c']</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>?&</literal></entry>
|
|
<entry><type>text[]</type></entry>
|
|
<entry>Do all of these array <emphasis>strings</emphasis> exist
|
|
as top-level keys?</entry>
|
|
<entry><literal>'["a", "b"]'::jsonb ?& array['a', 'b']</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>||</literal></entry>
|
|
<entry><type>jsonb</type></entry>
|
|
<entry>Concatenate two <type>jsonb</type> values into a new <type>jsonb</type> value</entry>
|
|
<entry><literal>'["a", "b"]'::jsonb || '["c", "d"]'::jsonb</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>-</literal></entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>Delete key/value pair or <emphasis>string</emphasis>
|
|
element from left operand. Key/value pairs are matched based
|
|
on their key value.</entry>
|
|
<entry><literal>'{"a": "b"}'::jsonb - 'a' </literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>-</literal></entry>
|
|
<entry><type>text[]</type></entry>
|
|
<entry>Delete multiple key/value pairs or <emphasis>string</emphasis>
|
|
elements from left operand. Key/value pairs are matched based
|
|
on their key value.</entry>
|
|
<entry><literal>'{"a": "b", "c": "d"}'::jsonb - '{a,c}'::text[] </literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>-</literal></entry>
|
|
<entry><type>integer</type></entry>
|
|
<entry>Delete the array element with specified index (Negative
|
|
integers count from the end). Throws an error if top level
|
|
container is not an array.</entry>
|
|
<entry><literal>'["a", "b"]'::jsonb - 1 </literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>#-</literal></entry>
|
|
<entry><type>text[]</type></entry>
|
|
<entry>Delete the field or element with specified path (for
|
|
JSON arrays, negative integers count from the end)</entry>
|
|
<entry><literal>'["a", {"b":1}]'::jsonb #- '{1,b}'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>@?</literal></entry>
|
|
<entry><type>jsonpath</type></entry>
|
|
<entry>Does JSON path return any item for the specified JSON value?</entry>
|
|
<entry><literal>'{"a":[1,2,3,4,5]}'::jsonb @? '$.a[*] ? (@ > 2)'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>@@</literal></entry>
|
|
<entry><type>jsonpath</type></entry>
|
|
<entry>Returns the result of JSON path predicate check for the specified JSON value.
|
|
Only the first item of the result is taken into account. If the
|
|
result is not Boolean, then <literal>null</literal> is returned.</entry>
|
|
<entry><literal>'{"a":[1,2,3,4,5]}'::jsonb @@ '$.a[*] > 2'</literal></entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<note>
|
|
<para>
|
|
The <literal>||</literal> operator concatenates the elements at the top level of
|
|
each of its operands. It does not operate recursively. For example, if
|
|
both operands are objects with a common key field name, the value of the
|
|
field in the result will just be the value from the right hand operand.
|
|
</para>
|
|
</note>
|
|
|
|
<note>
|
|
<para>
|
|
The <literal>@?</literal> and <literal>@@</literal> operators suppress
|
|
the following errors: lacking object field or array element, unexpected
|
|
JSON item type, and numeric errors.
|
|
This behavior might be helpful while searching over JSON document
|
|
collections of varying structure.
|
|
</para>
|
|
</note>
|
|
|
|
<para>
|
|
<xref linkend="functions-json-creation-table"/> shows the functions that are
|
|
available for creating <type>json</type> and <type>jsonb</type> values.
|
|
(There are no equivalent functions for <type>jsonb</type>, of the <literal>row_to_json</literal>
|
|
and <literal>array_to_json</literal> functions. However, the <literal>to_jsonb</literal>
|
|
function supplies much the same functionality as these functions would.)
|
|
</para>
|
|
|
|
<indexterm>
|
|
<primary>to_json</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>array_to_json</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>row_to_json</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>json_build_array</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>json_build_object</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>json_object</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>to_jsonb</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>jsonb_build_array</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>jsonb_build_object</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>jsonb_object</primary>
|
|
</indexterm>
|
|
|
|
<table id="functions-json-creation-table">
|
|
<title>JSON Creation 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><para><literal>to_json(anyelement)</literal>
|
|
</para><para><literal>to_jsonb(anyelement)</literal>
|
|
</para></entry>
|
|
<entry>
|
|
Returns the value as <type>json</type> or <type>jsonb</type>.
|
|
Arrays and composites are converted
|
|
(recursively) to arrays and objects; otherwise, if there is a cast
|
|
from the type to <type>json</type>, the cast function will be used to
|
|
perform the conversion; otherwise, a scalar value is produced.
|
|
For any scalar type other than a number, a Boolean, or a null value,
|
|
the text representation will be used, in such a fashion that it is a
|
|
valid <type>json</type> or <type>jsonb</type> value.
|
|
</entry>
|
|
<entry><literal>to_json('Fred said "Hi."'::text)</literal></entry>
|
|
<entry><literal>"Fred said \"Hi.\""</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal>array_to_json(anyarray [, pretty_bool])</literal>
|
|
</entry>
|
|
<entry>
|
|
Returns the array as a JSON array. A PostgreSQL multidimensional array
|
|
becomes a JSON array of arrays. Line feeds will be added between
|
|
dimension-1 elements if <parameter>pretty_bool</parameter> is true.
|
|
</entry>
|
|
<entry><literal>array_to_json('{{1,5},{99,100}}'::int[])</literal></entry>
|
|
<entry><literal>[[1,5],[99,100]]</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal>row_to_json(record [, pretty_bool])</literal>
|
|
</entry>
|
|
<entry>
|
|
Returns the row as a JSON object. Line feeds will be added between
|
|
level-1 elements if <parameter>pretty_bool</parameter> is true.
|
|
</entry>
|
|
<entry><literal>row_to_json(row(1,'foo'))</literal></entry>
|
|
<entry><literal>{"f1":1,"f2":"foo"}</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><para><literal>json_build_array(VARIADIC "any")</literal>
|
|
</para><para><literal>jsonb_build_array(VARIADIC "any")</literal>
|
|
</para></entry>
|
|
<entry>
|
|
Builds a possibly-heterogeneously-typed JSON array out of a variadic
|
|
argument list.
|
|
</entry>
|
|
<entry><literal>json_build_array(1,2,'3',4,5)</literal></entry>
|
|
<entry><literal>[1, 2, "3", 4, 5]</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><para><literal>json_build_object(VARIADIC "any")</literal>
|
|
</para><para><literal>jsonb_build_object(VARIADIC "any")</literal>
|
|
</para></entry>
|
|
<entry>
|
|
Builds a JSON object out of a variadic argument list. By
|
|
convention, the argument list consists of alternating
|
|
keys and values.
|
|
</entry>
|
|
<entry><literal>json_build_object('foo',1,'bar',2)</literal></entry>
|
|
<entry><literal>{"foo": 1, "bar": 2}</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><para><literal>json_object(text[])</literal>
|
|
</para><para><literal>jsonb_object(text[])</literal>
|
|
</para></entry>
|
|
<entry>
|
|
Builds a JSON object out of a text array. The array must have either
|
|
exactly one dimension with an even number of members, in which case
|
|
they are taken as alternating key/value pairs, or two dimensions
|
|
such that each inner array has exactly two elements, which
|
|
are taken as a key/value pair.
|
|
</entry>
|
|
<entry><para><literal>json_object('{a, 1, b, "def", c, 3.5}')</literal></para>
|
|
<para><literal>json_object('{{a, 1},{b, "def"},{c, 3.5}}')</literal></para></entry>
|
|
<entry><literal>{"a": "1", "b": "def", "c": "3.5"}</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><para><literal>json_object(keys text[], values text[])</literal>
|
|
</para><para><literal>jsonb_object(keys text[], values text[])</literal>
|
|
</para></entry>
|
|
<entry>
|
|
This form of <function>json_object</function> takes keys and values pairwise from two separate
|
|
arrays. In all other respects it is identical to the one-argument form.
|
|
</entry>
|
|
<entry><literal>json_object('{a, b}', '{1,2}')</literal></entry>
|
|
<entry><literal>{"a": "1", "b": "2"}</literal></entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<note>
|
|
<para>
|
|
<function>array_to_json</function> and <function>row_to_json</function> have the same
|
|
behavior as <function>to_json</function> except for offering a pretty-printing
|
|
option. The behavior described for <function>to_json</function> likewise applies
|
|
to each individual value converted by the other JSON creation functions.
|
|
</para>
|
|
</note>
|
|
|
|
<note>
|
|
<para>
|
|
The <xref linkend="hstore"/> extension has a cast
|
|
from <type>hstore</type> to <type>json</type>, so that
|
|
<type>hstore</type> values converted via the JSON creation functions
|
|
will be represented as JSON objects, not as primitive string values.
|
|
</para>
|
|
</note>
|
|
|
|
<para>
|
|
<xref linkend="functions-json-processing-table"/> shows the functions that
|
|
are available for processing <type>json</type> and <type>jsonb</type> values.
|
|
</para>
|
|
|
|
<indexterm>
|
|
<primary>json_array_length</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>jsonb_array_length</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>json_each</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>jsonb_each</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>json_each_text</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>jsonb_each_text</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>json_extract_path</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>jsonb_extract_path</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>json_extract_path_text</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>jsonb_extract_path_text</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>json_object_keys</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>jsonb_object_keys</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>json_populate_record</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>jsonb_populate_record</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>json_populate_recordset</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>jsonb_populate_recordset</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>json_array_elements</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>jsonb_array_elements</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>json_array_elements_text</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>jsonb_array_elements_text</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>json_typeof</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>jsonb_typeof</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>json_to_record</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>jsonb_to_record</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>json_to_recordset</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>jsonb_to_recordset</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>json_strip_nulls</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>jsonb_strip_nulls</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>jsonb_set</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>jsonb_insert</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>jsonb_pretty</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>jsonb_path_exists</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>jsonb_path_match</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>jsonb_path_query</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>jsonb_path_query_array</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>jsonb_path_query_first</primary>
|
|
</indexterm>
|
|
|
|
<table id="functions-json-processing-table">
|
|
<title>JSON Processing Functions</title>
|
|
<tgroup cols="5">
|
|
<thead>
|
|
<row>
|
|
<entry>Function</entry>
|
|
<entry>Return Type</entry>
|
|
<entry>Description</entry>
|
|
<entry>Example</entry>
|
|
<entry>Example Result</entry>
|
|
</row>
|
|
</thead>
|
|
<tbody>
|
|
<row>
|
|
<entry><para><literal>json_array_length(json)</literal>
|
|
</para><para><literal>jsonb_array_length(jsonb)</literal>
|
|
</para></entry>
|
|
<entry><type>int</type></entry>
|
|
<entry>
|
|
Returns the number of elements in the outermost JSON array.
|
|
</entry>
|
|
<entry><literal>json_array_length('[1,2,3,{"f1":1,"f2":[5,6]},4]')</literal></entry>
|
|
<entry><literal>5</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><para><literal>json_each(json)</literal>
|
|
</para><para><literal>jsonb_each(jsonb)</literal>
|
|
</para></entry>
|
|
<entry><para><literal>setof key text, value json</literal>
|
|
</para><para><literal>setof key text, value jsonb</literal>
|
|
</para></entry>
|
|
<entry>
|
|
Expands the outermost JSON object into a set of key/value pairs.
|
|
</entry>
|
|
<entry><literal>select * from json_each('{"a":"foo", "b":"bar"}')</literal></entry>
|
|
<entry>
|
|
<programlisting>
|
|
key | value
|
|
-----+-------
|
|
a | "foo"
|
|
b | "bar"
|
|
</programlisting>
|
|
</entry>
|
|
</row>
|
|
<row>
|
|
<entry><para><literal>json_each_text(json)</literal>
|
|
</para><para><literal>jsonb_each_text(jsonb)</literal>
|
|
</para></entry>
|
|
<entry><type>setof key text, value text</type></entry>
|
|
<entry>
|
|
Expands the outermost JSON object into a set of key/value pairs. The
|
|
returned values will be of type <type>text</type>.
|
|
</entry>
|
|
<entry><literal>select * from json_each_text('{"a":"foo", "b":"bar"}')</literal></entry>
|
|
<entry>
|
|
<programlisting>
|
|
key | value
|
|
-----+-------
|
|
a | foo
|
|
b | bar
|
|
</programlisting>
|
|
</entry>
|
|
</row>
|
|
<row>
|
|
<entry><para><literal>json_extract_path(from_json json, VARIADIC path_elems text[])</literal>
|
|
</para><para><literal>jsonb_extract_path(from_json jsonb, VARIADIC path_elems text[])</literal>
|
|
</para></entry>
|
|
<entry><para><type>json</type></para><para><type>jsonb</type>
|
|
</para></entry>
|
|
<entry>
|
|
Returns JSON value pointed to by <replaceable>path_elems</replaceable>
|
|
(equivalent to <literal>#></literal> operator).
|
|
</entry>
|
|
<entry><literal>json_extract_path('{"f2":{"f3":1},"f4":{"f5":99,"f6":"foo"}}','f4')</literal></entry>
|
|
<entry><literal>{"f5":99,"f6":"foo"}</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><para><literal>json_extract_path_text(from_json json, VARIADIC path_elems text[])</literal>
|
|
</para><para><literal>jsonb_extract_path_text(from_json jsonb, VARIADIC path_elems text[])</literal>
|
|
</para></entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>
|
|
Returns JSON value pointed to by <replaceable>path_elems</replaceable>
|
|
as <type>text</type>
|
|
(equivalent to <literal>#>></literal> operator).
|
|
</entry>
|
|
<entry><literal>json_extract_path_text('{"f2":{"f3":1},"f4":{"f5":99,"f6":"foo"}}','f4', 'f6')</literal></entry>
|
|
<entry><literal>foo</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><para><literal>json_object_keys(json)</literal>
|
|
</para><para><literal>jsonb_object_keys(jsonb)</literal>
|
|
</para></entry>
|
|
<entry><type>setof text</type></entry>
|
|
<entry>
|
|
Returns set of keys in the outermost JSON object.
|
|
</entry>
|
|
<entry><literal>json_object_keys('{"f1":"abc","f2":{"f3":"a", "f4":"b"}}')</literal></entry>
|
|
<entry>
|
|
<programlisting>
|
|
json_object_keys
|
|
------------------
|
|
f1
|
|
f2
|
|
</programlisting>
|
|
</entry>
|
|
</row>
|
|
<row>
|
|
<entry><para><literal>json_populate_record(base anyelement, from_json json)</literal>
|
|
</para><para><literal>jsonb_populate_record(base anyelement, from_json jsonb)</literal>
|
|
</para></entry>
|
|
<entry><type>anyelement</type></entry>
|
|
<entry>
|
|
Expands the object in <replaceable>from_json</replaceable> to a row
|
|
whose columns match the record type defined by <replaceable>base</replaceable>
|
|
(see note below).
|
|
</entry>
|
|
<entry><literal>select * from json_populate_record(null::myrowtype, '{"a": 1, "b": ["2", "a b"], "c": {"d": 4, "e": "a b c"}}')</literal></entry>
|
|
<entry>
|
|
<programlisting>
|
|
a | b | c
|
|
---+-----------+-------------
|
|
1 | {2,"a b"} | (4,"a b c")
|
|
</programlisting>
|
|
</entry>
|
|
</row>
|
|
<row>
|
|
<entry><para><literal>json_populate_recordset(base anyelement, from_json json)</literal>
|
|
</para><para><literal>jsonb_populate_recordset(base anyelement, from_json jsonb)</literal>
|
|
</para></entry>
|
|
<entry><type>setof anyelement</type></entry>
|
|
<entry>
|
|
Expands the outermost array of objects
|
|
in <replaceable>from_json</replaceable> to a set of rows whose
|
|
columns match the record type defined by <replaceable>base</replaceable> (see
|
|
note below).
|
|
</entry>
|
|
<entry><literal>select * from json_populate_recordset(null::myrowtype, '[{"a":1,"b":2},{"a":3,"b":4}]')</literal></entry>
|
|
<entry>
|
|
<programlisting>
|
|
a | b
|
|
---+---
|
|
1 | 2
|
|
3 | 4
|
|
</programlisting>
|
|
</entry>
|
|
</row>
|
|
<row>
|
|
<entry><para><literal>json_array_elements(json)</literal>
|
|
</para><para><literal>jsonb_array_elements(jsonb)</literal>
|
|
</para></entry>
|
|
<entry><para><type>setof json</type>
|
|
</para><para><type>setof jsonb</type>
|
|
</para></entry>
|
|
<entry>
|
|
Expands a JSON array to a set of JSON values.
|
|
</entry>
|
|
<entry><literal>select * from json_array_elements('[1,true, [2,false]]')</literal></entry>
|
|
<entry>
|
|
<programlisting>
|
|
value
|
|
-----------
|
|
1
|
|
true
|
|
[2,false]
|
|
</programlisting>
|
|
</entry>
|
|
</row>
|
|
<row>
|
|
<entry><para><literal>json_array_elements_text(json)</literal>
|
|
</para><para><literal>jsonb_array_elements_text(jsonb)</literal>
|
|
</para></entry>
|
|
<entry><type>setof text</type></entry>
|
|
<entry>
|
|
Expands a JSON array to a set of <type>text</type> values.
|
|
</entry>
|
|
<entry><literal>select * from json_array_elements_text('["foo", "bar"]')</literal></entry>
|
|
<entry>
|
|
<programlisting>
|
|
value
|
|
-----------
|
|
foo
|
|
bar
|
|
</programlisting>
|
|
</entry>
|
|
</row>
|
|
<row>
|
|
<entry><para><literal>json_typeof(json)</literal>
|
|
</para><para><literal>jsonb_typeof(jsonb)</literal>
|
|
</para></entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>
|
|
Returns the type of the outermost JSON value as a text string.
|
|
Possible types are
|
|
<literal>object</literal>, <literal>array</literal>, <literal>string</literal>, <literal>number</literal>,
|
|
<literal>boolean</literal>, and <literal>null</literal>.
|
|
</entry>
|
|
<entry><literal>json_typeof('-123.4')</literal></entry>
|
|
<entry><literal>number</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><para><literal>json_to_record(json)</literal>
|
|
</para><para><literal>jsonb_to_record(jsonb)</literal>
|
|
</para></entry>
|
|
<entry><type>record</type></entry>
|
|
<entry>
|
|
Builds an arbitrary record from a JSON object (see note below). As
|
|
with all functions returning <type>record</type>, the caller must
|
|
explicitly define the structure of the record with an <literal>AS</literal>
|
|
clause.
|
|
</entry>
|
|
<entry><literal>select * from json_to_record('{"a":1,"b":[1,2,3],"c":[1,2,3],"e":"bar","r": {"a": 123, "b": "a b c"}}') as x(a int, b text, c int[], d text, r myrowtype) </literal></entry>
|
|
<entry>
|
|
<programlisting>
|
|
a | b | c | d | r
|
|
---+---------+---------+---+---------------
|
|
1 | [1,2,3] | {1,2,3} | | (123,"a b c")
|
|
</programlisting>
|
|
</entry>
|
|
</row>
|
|
<row>
|
|
<entry><para><literal>json_to_recordset(json)</literal>
|
|
</para><para><literal>jsonb_to_recordset(jsonb)</literal>
|
|
</para></entry>
|
|
<entry><type>setof record</type></entry>
|
|
<entry>
|
|
Builds an arbitrary set of records from a JSON array of objects (see
|
|
note below). As with all functions returning <type>record</type>, the
|
|
caller must explicitly define the structure of the record with
|
|
an <literal>AS</literal> clause.
|
|
</entry>
|
|
<entry><literal>select * from json_to_recordset('[{"a":1,"b":"foo"},{"a":"2","c":"bar"}]') as x(a int, b text);</literal></entry>
|
|
<entry>
|
|
<programlisting>
|
|
a | b
|
|
---+-----
|
|
1 | foo
|
|
2 |
|
|
</programlisting>
|
|
</entry>
|
|
</row>
|
|
<row>
|
|
<entry><para><literal>json_strip_nulls(from_json json)</literal>
|
|
</para><para><literal>jsonb_strip_nulls(from_json jsonb)</literal>
|
|
</para></entry>
|
|
<entry><para><type>json</type></para><para><type>jsonb</type></para></entry>
|
|
<entry>
|
|
Returns <replaceable>from_json</replaceable>
|
|
with all object fields that have null values omitted. Other null values
|
|
are untouched.
|
|
</entry>
|
|
<entry><literal>json_strip_nulls('[{"f1":1,"f2":null},2,null,3]')</literal></entry>
|
|
<entry><literal>[{"f1":1},2,null,3]</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><para><literal>jsonb_set(target jsonb, path text[], new_value jsonb <optional>, create_missing boolean</optional>)</literal>
|
|
</para></entry>
|
|
<entry><para><type>jsonb</type></para></entry>
|
|
<entry>
|
|
Returns <replaceable>target</replaceable>
|
|
with the section designated by <replaceable>path</replaceable>
|
|
replaced by <replaceable>new_value</replaceable>, or with
|
|
<replaceable>new_value</replaceable> added if
|
|
<replaceable>create_missing</replaceable> is true (default is
|
|
<literal>true</literal>) and the item
|
|
designated by <replaceable>path</replaceable> does not exist.
|
|
As with the path oriented operators, negative integers that
|
|
appear in <replaceable>path</replaceable> count from the end
|
|
of JSON arrays.
|
|
</entry>
|
|
<entry><para><literal>jsonb_set('[{"f1":1,"f2":null},2,null,3]', '{0,f1}','[2,3,4]', false)</literal>
|
|
</para><para><literal>jsonb_set('[{"f1":1,"f2":null},2]', '{0,f3}','[2,3,4]')</literal>
|
|
</para></entry>
|
|
<entry><para><literal>[{"f1":[2,3,4],"f2":null},2,null,3]</literal>
|
|
</para><para><literal>[{"f1": 1, "f2": null, "f3": [2, 3, 4]}, 2]</literal>
|
|
</para></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<para><literal>
|
|
jsonb_insert(target jsonb, path text[], new_value jsonb <optional>, insert_after boolean</optional>)
|
|
</literal></para>
|
|
</entry>
|
|
<entry><para><type>jsonb</type></para></entry>
|
|
<entry>
|
|
Returns <replaceable>target</replaceable> with
|
|
<replaceable>new_value</replaceable> inserted. If
|
|
<replaceable>target</replaceable> section designated by
|
|
<replaceable>path</replaceable> is in a JSONB array,
|
|
<replaceable>new_value</replaceable> will be inserted before target or
|
|
after if <replaceable>insert_after</replaceable> is true (default is
|
|
<literal>false</literal>). If <replaceable>target</replaceable> section
|
|
designated by <replaceable>path</replaceable> is in JSONB object,
|
|
<replaceable>new_value</replaceable> will be inserted only if
|
|
<replaceable>target</replaceable> does not exist. As with the path
|
|
oriented operators, negative integers that appear in
|
|
<replaceable>path</replaceable> count from the end of JSON arrays.
|
|
</entry>
|
|
<entry>
|
|
<para><literal>
|
|
jsonb_insert('{"a": [0,1,2]}', '{a, 1}', '"new_value"')
|
|
</literal></para>
|
|
<para><literal>
|
|
jsonb_insert('{"a": [0,1,2]}', '{a, 1}', '"new_value"', true)
|
|
</literal></para>
|
|
</entry>
|
|
<entry><para><literal>{"a": [0, "new_value", 1, 2]}</literal>
|
|
</para><para><literal>{"a": [0, 1, "new_value", 2]}</literal>
|
|
</para></entry>
|
|
</row>
|
|
<row>
|
|
<entry><para><literal>jsonb_pretty(from_json jsonb)</literal>
|
|
</para></entry>
|
|
<entry><para><type>text</type></para></entry>
|
|
<entry>
|
|
Returns <replaceable>from_json</replaceable>
|
|
as indented JSON text.
|
|
</entry>
|
|
<entry><literal>jsonb_pretty('[{"f1":1,"f2":null},2,null,3]')</literal></entry>
|
|
<entry>
|
|
<programlisting>
|
|
[
|
|
{
|
|
"f1": 1,
|
|
"f2": null
|
|
},
|
|
2,
|
|
null,
|
|
3
|
|
]
|
|
</programlisting>
|
|
</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<para><literal>
|
|
jsonb_path_exists(target jsonb, path jsonpath <optional>, vars jsonb <optional>, silent bool</optional></optional>)
|
|
</literal></para>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>
|
|
Checks whether JSON path returns any item for the specified JSON
|
|
value.
|
|
</entry>
|
|
<entry>
|
|
<para><literal>
|
|
jsonb_path_exists('{"a":[1,2,3,4,5]}', '$.a[*] ? (@ >= $min && @ <= $max)', '{"min":2,"max":4}')
|
|
</literal></para>
|
|
</entry>
|
|
<entry>
|
|
<para><literal>true</literal></para>
|
|
</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<para><literal>
|
|
jsonb_path_match(target jsonb, path jsonpath <optional>, vars jsonb <optional>, silent bool</optional></optional>)
|
|
</literal></para>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>
|
|
Returns the result of JSON path predicate check for the specified JSON value.
|
|
Only the first item of the result is taken into account. If the
|
|
result is not Boolean, then <literal>null</literal> is returned.
|
|
</entry>
|
|
<entry>
|
|
<para><literal>
|
|
jsonb_path_match('{"a":[1,2,3,4,5]}', 'exists($.a[*] ? (@ >= $min && @ <= $max))', '{"min":2,"max":4}')
|
|
</literal></para>
|
|
</entry>
|
|
<entry>
|
|
<para><literal>true</literal></para>
|
|
</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<para><literal>
|
|
jsonb_path_query(target jsonb, path jsonpath <optional>, vars jsonb <optional>, silent bool</optional></optional>)
|
|
</literal></para>
|
|
</entry>
|
|
<entry><type>setof jsonb</type></entry>
|
|
<entry>
|
|
Gets all JSON items returned by JSON path for the specified JSON
|
|
value.
|
|
</entry>
|
|
<entry>
|
|
<para><literal>
|
|
select * from jsonb_path_query('{"a":[1,2,3,4,5]}', '$.a[*] ? (@ >= $min && @ <= $max)', '{"min":2,"max":4}');
|
|
</literal></para>
|
|
</entry>
|
|
<entry>
|
|
<para>
|
|
<programlisting>
|
|
jsonb_path_query
|
|
------------------
|
|
2
|
|
3
|
|
4
|
|
</programlisting>
|
|
</para>
|
|
</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<para><literal>
|
|
jsonb_path_query_array(target jsonb, path jsonpath <optional>, vars jsonb <optional>, silent bool</optional></optional>)
|
|
</literal></para>
|
|
</entry>
|
|
<entry><type>jsonb</type></entry>
|
|
<entry>
|
|
Gets all JSON items returned by JSON path for the specified JSON
|
|
value and wraps result into an array.
|
|
</entry>
|
|
<entry>
|
|
<para><literal>
|
|
jsonb_path_query_array('{"a":[1,2,3,4,5]}', '$.a[*] ? (@ >= $min && @ <= $max)', '{"min":2,"max":4}')
|
|
</literal></para>
|
|
</entry>
|
|
<entry>
|
|
<para><literal>[2, 3, 4]</literal></para>
|
|
</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<para><literal>
|
|
jsonb_path_query_first(target jsonb, path jsonpath <optional>, vars jsonb <optional>, silent bool</optional></optional>)
|
|
</literal></para>
|
|
</entry>
|
|
<entry><type>jsonb</type></entry>
|
|
<entry>
|
|
Gets the first JSON item returned by JSON path for the specified JSON
|
|
value. Returns <literal>NULL</literal> on no results.
|
|
</entry>
|
|
<entry>
|
|
<para><literal>
|
|
jsonb_path_query_first('{"a":[1,2,3,4,5]}', '$.a[*] ? (@ >= $min && @ <= $max)', '{"min":2,"max":4}')
|
|
</literal></para>
|
|
</entry>
|
|
<entry>
|
|
<para><literal>2</literal></para>
|
|
</entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<note>
|
|
<para>
|
|
Many of these functions and operators will convert Unicode escapes in
|
|
JSON strings to the appropriate single character. This is a non-issue
|
|
if the input is type <type>jsonb</type>, because the conversion was already
|
|
done; but for <type>json</type> input, this may result in throwing an error,
|
|
as noted in <xref linkend="datatype-json"/>.
|
|
</para>
|
|
</note>
|
|
|
|
<note>
|
|
<para>
|
|
The functions
|
|
<function>json[b]_populate_record</function>,
|
|
<function>json[b]_populate_recordset</function>,
|
|
<function>json[b]_to_record</function> and
|
|
<function>json[b]_to_recordset</function>
|
|
operate on a JSON object, or array of objects, and extract the values
|
|
associated with keys whose names match column names of the output row
|
|
type.
|
|
Object fields that do not correspond to any output column name are
|
|
ignored, and output columns that do not match any object field will be
|
|
filled with nulls.
|
|
To convert a JSON value to the SQL type of an output column, the
|
|
following rules are applied in sequence:
|
|
<itemizedlist spacing="compact">
|
|
<listitem>
|
|
<para>
|
|
A JSON null value is converted to a SQL null in all cases.
|
|
</para>
|
|
</listitem>
|
|
<listitem>
|
|
<para>
|
|
If the output column is of type <type>json</type>
|
|
or <type>jsonb</type>, the JSON value is just reproduced exactly.
|
|
</para>
|
|
</listitem>
|
|
<listitem>
|
|
<para>
|
|
If the output column is a composite (row) type, and the JSON value is
|
|
a JSON object, the fields of the object are converted to columns of
|
|
the output row type by recursive application of these rules.
|
|
</para>
|
|
</listitem>
|
|
<listitem>
|
|
<para>
|
|
Likewise, if the output column is an array type and the JSON value is
|
|
a JSON array, the elements of the JSON array are converted to elements
|
|
of the output array by recursive application of these rules.
|
|
</para>
|
|
</listitem>
|
|
<listitem>
|
|
<para>
|
|
Otherwise, if the JSON value is a string literal, the contents of the
|
|
string are fed to the input conversion function for the column's data
|
|
type.
|
|
</para>
|
|
</listitem>
|
|
<listitem>
|
|
<para>
|
|
Otherwise, the ordinary text representation of the JSON value is fed
|
|
to the input conversion function for the column's data type.
|
|
</para>
|
|
</listitem>
|
|
</itemizedlist>
|
|
</para>
|
|
|
|
<para>
|
|
While the examples for these functions use constants, the typical use
|
|
would be to reference a table in the <literal>FROM</literal> clause
|
|
and use one of its <type>json</type> or <type>jsonb</type> columns
|
|
as an argument to the function. Extracted key values can then be
|
|
referenced in other parts of the query, like <literal>WHERE</literal>
|
|
clauses and target lists. Extracting multiple values in this
|
|
way can improve performance over extracting them separately with
|
|
per-key operators.
|
|
</para>
|
|
</note>
|
|
|
|
<note>
|
|
<para>
|
|
All the items of the <literal>path</literal> parameter of <literal>jsonb_set</literal>
|
|
as well as <literal>jsonb_insert</literal> except the last item must be present
|
|
in the <literal>target</literal>. If <literal>create_missing</literal> is false, all
|
|
items of the <literal>path</literal> parameter of <literal>jsonb_set</literal> must be
|
|
present. If these conditions are not met the <literal>target</literal> is
|
|
returned unchanged.
|
|
</para>
|
|
<para>
|
|
If the last path item is an object key, it will be created if it
|
|
is absent and given the new value. If the last path item is an array
|
|
index, if it is positive the item to set is found by counting from
|
|
the left, and if negative by counting from the right - <literal>-1</literal>
|
|
designates the rightmost element, and so on.
|
|
If the item is out of the range -array_length .. array_length -1,
|
|
and create_missing is true, the new value is added at the beginning
|
|
of the array if the item is negative, and at the end of the array if
|
|
it is positive.
|
|
</para>
|
|
</note>
|
|
|
|
<note>
|
|
<para>
|
|
The <literal>json_typeof</literal> function's <literal>null</literal> return value
|
|
should not be confused with a SQL NULL. While
|
|
calling <literal>json_typeof('null'::json)</literal> will
|
|
return <literal>null</literal>, calling <literal>json_typeof(NULL::json)</literal>
|
|
will return a SQL NULL.
|
|
</para>
|
|
</note>
|
|
|
|
<note>
|
|
<para>
|
|
If the argument to <literal>json_strip_nulls</literal> contains duplicate
|
|
field names in any object, the result could be semantically somewhat
|
|
different, depending on the order in which they occur. This is not an
|
|
issue for <literal>jsonb_strip_nulls</literal> since <type>jsonb</type> values never have
|
|
duplicate object field names.
|
|
</para>
|
|
</note>
|
|
|
|
<note>
|
|
<para>
|
|
The <literal>jsonb_path_exists</literal>, <literal>jsonb_path_match</literal>,
|
|
<literal>jsonb_path_query</literal>, <literal>jsonb_path_query_array</literal>, and
|
|
<literal>jsonb_path_query_first</literal>
|
|
functions have optional <literal>vars</literal> and <literal>silent</literal>
|
|
arguments.
|
|
</para>
|
|
<para>
|
|
If the <parameter>vars</parameter> argument is specified, it provides an
|
|
object containing named variables to be substituted into a
|
|
<literal>jsonpath</literal> expression.
|
|
</para>
|
|
<para>
|
|
If the <parameter>silent</parameter> argument is specified and has the
|
|
<literal>true</literal> value, these functions suppress the same errors
|
|
as the <literal>@?</literal> and <literal>@@</literal> operators.
|
|
</para>
|
|
</note>
|
|
|
|
<para>
|
|
See also <xref linkend="functions-aggregate"/> for the aggregate
|
|
function <function>json_agg</function> which aggregates record
|
|
values as JSON, and the aggregate function
|
|
<function>json_object_agg</function> which aggregates pairs of values
|
|
into a JSON object, and their <type>jsonb</type> equivalents,
|
|
<function>jsonb_agg</function> and <function>jsonb_object_agg</function>.
|
|
</para>
|
|
|
|
</sect2>
|
|
|
|
<sect2 id="functions-sqljson-path">
|
|
<title>The SQL/JSON Path Language</title>
|
|
|
|
<indexterm zone="functions-sqljson-path">
|
|
<primary>SQL/JSON path language</primary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
SQL/JSON path expressions specify the items to be retrieved
|
|
from the JSON data, similar to XPath expressions used
|
|
for SQL access to XML. In <productname>PostgreSQL</productname>,
|
|
path expressions are implemented as the <type>jsonpath</type>
|
|
data type and can use any elements described in
|
|
<xref linkend="datatype-jsonpath"/>.
|
|
</para>
|
|
|
|
<para>JSON query functions and operators
|
|
pass the provided path expression to the <firstterm>path engine</firstterm>
|
|
for evaluation. If the expression matches the queried JSON data,
|
|
the corresponding SQL/JSON item is returned.
|
|
Path expressions are written in the SQL/JSON path language
|
|
and can also include arithmetic expressions and functions.
|
|
Query functions treat the provided expression as a
|
|
text string, so it must be enclosed in single quotes.
|
|
</para>
|
|
|
|
<para>
|
|
A path expression consists of a sequence of elements allowed
|
|
by the <type>jsonpath</type> data type.
|
|
The path expression is evaluated from left to right, but
|
|
you can use parentheses to change the order of operations.
|
|
If the evaluation is successful, a sequence of SQL/JSON items
|
|
(<firstterm>SQL/JSON sequence</firstterm>) is produced,
|
|
and the evaluation result is returned to the JSON query function
|
|
that completes the specified computation.
|
|
</para>
|
|
|
|
<para>
|
|
To refer to the JSON data to be queried (the
|
|
<firstterm>context item</firstterm>), use the <literal>$</literal> sign
|
|
in the path expression. It can be followed by one or more
|
|
<link linkend="type-jsonpath-accessors">accessor operators</link>,
|
|
which go down the JSON structure level by level to retrieve the
|
|
content of context item. Each operator that follows deals with the
|
|
result of the previous evaluation step.
|
|
</para>
|
|
|
|
<para>
|
|
For example, suppose you have some JSON data from a GPS tracker that you
|
|
would like to parse, such as:
|
|
<programlisting>
|
|
{
|
|
"track": {
|
|
"segments": [
|
|
{
|
|
"location": [ 47.763, 13.4034 ],
|
|
"start time": "2018-10-14 10:05:14",
|
|
"HR": 73
|
|
},
|
|
{
|
|
"location": [ 47.706, 13.2635 ],
|
|
"start time": "2018-10-14 10:39:21",
|
|
"HR": 135
|
|
}
|
|
]
|
|
}
|
|
}
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
To retrieve the available track segments, you need to use the
|
|
<literal>.<replaceable>key</replaceable></literal> accessor
|
|
operator for all the preceding JSON objects:
|
|
<programlisting>
|
|
'$.track.segments'
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
If the item to retrieve is an element of an array, you have
|
|
to unnest this array using the <literal>[*]</literal> operator. For example,
|
|
the following path will return location coordinates for all
|
|
the available track segments:
|
|
<programlisting>
|
|
'$.track.segments[*].location'
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
To return the coordinates of the first segment only, you can
|
|
specify the corresponding subscript in the <literal>[]</literal>
|
|
accessor operator. Note that the SQL/JSON arrays are 0-relative:
|
|
<programlisting>
|
|
'$.track.segments[0].location'
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
The result of each path evaluation step can be processed
|
|
by one or more <type>jsonpath</type> operators and methods
|
|
listed in <xref linkend="functions-sqljson-path-operators"/>.
|
|
Each method name must be preceded by a dot. For example,
|
|
you can get an array size:
|
|
<programlisting>
|
|
'$.track.segments.size()'
|
|
</programlisting>
|
|
For more examples of using <type>jsonpath</type> operators
|
|
and methods within path expressions, see
|
|
<xref linkend="functions-sqljson-path-operators"/>.
|
|
</para>
|
|
|
|
<para>
|
|
When defining the path, you can also use one or more
|
|
<firstterm>filter expressions</firstterm> that work similar to the
|
|
<literal>WHERE</literal> clause in SQL. A filter expression begins with
|
|
a question mark and provides a condition in parentheses:
|
|
|
|
<programlisting>
|
|
? (<replaceable>condition</replaceable>)
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
Filter expressions must be specified right after the path evaluation step
|
|
to which they are applied. The result of this step is filtered to include
|
|
only those items that satisfy the provided condition. SQL/JSON defines
|
|
three-valued logic, so the condition can be <literal>true</literal>, <literal>false</literal>,
|
|
or <literal>unknown</literal>. The <literal>unknown</literal> value
|
|
plays the same role as SQL <literal>NULL</literal> and can be tested
|
|
for with the <literal>is unknown</literal> predicate. Further path
|
|
evaluation steps use only those items for which filter expressions
|
|
return <literal>true</literal>.
|
|
</para>
|
|
|
|
<para>
|
|
Functions and operators that can be used in filter expressions are listed
|
|
in <xref linkend="functions-sqljson-filter-ex-table"/>. The path
|
|
evaluation result to be filtered is denoted by the <literal>@</literal>
|
|
variable. To refer to a JSON element stored at a lower nesting level,
|
|
add one or more accessor operators after <literal>@</literal>.
|
|
</para>
|
|
|
|
<para>
|
|
Suppose you would like to retrieve all heart rate values higher
|
|
than 130. You can achieve this using the following expression:
|
|
<programlisting>
|
|
'$.track.segments[*].HR ? (@ > 130)'
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
To get the start time of segments with such values instead, you have to
|
|
filter out irrelevant segments before returning the start time, so the
|
|
filter expression is applied to the previous step, and the path used
|
|
in the condition is different:
|
|
<programlisting>
|
|
'$.track.segments[*] ? (@.HR > 130)."start time"'
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
You can use several filter expressions on the same nesting level, if
|
|
required. For example, the following expression selects all segments
|
|
that contain locations with relevant coordinates and high heart rate values:
|
|
<programlisting>
|
|
'$.track.segments[*] ? (@.location[1] < 13.4) ? (@.HR > 130)."start time"'
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
Using filter expressions at different nesting levels is also allowed.
|
|
The following example first filters all segments by location, and then
|
|
returns high heart rate values for these segments, if available:
|
|
<programlisting>
|
|
'$.track.segments[*] ? (@.location[1] < 13.4).HR ? (@ > 130)'
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
You can also nest filter expressions within each other:
|
|
<programlisting>
|
|
'$.track ? (exists(@.segments[*] ? (@.HR > 130))).segments.size()'
|
|
</programlisting>
|
|
This expression returns the size of the track if it contains any
|
|
segments with high heart rate values, or an empty sequence otherwise.
|
|
</para>
|
|
|
|
<para>
|
|
<productname>PostgreSQL</productname>'s implementation of SQL/JSON path
|
|
language has the following deviations from the SQL/JSON standard:
|
|
</para>
|
|
|
|
<itemizedlist>
|
|
<listitem>
|
|
<para>
|
|
<literal>.datetime()</literal> item method is not implemented yet
|
|
mainly because immutable <type>jsonpath</type> functions and operators
|
|
cannot reference session timezone, which is used in some datetime
|
|
operations. Datetime support will be added to <type>jsonpath</type>
|
|
in future versions of <productname>PostgreSQL</productname>.
|
|
</para>
|
|
</listitem>
|
|
|
|
<listitem>
|
|
<para>
|
|
A path expression can be a Boolean predicate, although the SQL/JSON
|
|
standard allows predicates only in filters. This is necessary for
|
|
implementation of the <literal>@@</literal> operator. For example,
|
|
the following <type>jsonpath</type> expression is valid in
|
|
<productname>PostgreSQL</productname>:
|
|
<programlisting>
|
|
'$.track.segments[*].HR < 70'
|
|
</programlisting>
|
|
</para>
|
|
</listitem>
|
|
|
|
<listitem>
|
|
<para>
|
|
There are minor differences in the interpretation of regular
|
|
expression patterns used in <literal>like_regex</literal> filters, as
|
|
described in <xref linkend="jsonpath-regular-expressions"/>.
|
|
</para>
|
|
</listitem>
|
|
</itemizedlist>
|
|
|
|
<sect3 id="strict-and-lax-modes">
|
|
<title>Strict and Lax Modes</title>
|
|
<para>
|
|
When you query JSON data, the path expression may not match the
|
|
actual JSON data structure. An attempt to access a non-existent
|
|
member of an object or element of an array results in a
|
|
structural error. SQL/JSON path expressions have two modes
|
|
of handling structural errors:
|
|
</para>
|
|
|
|
<itemizedlist>
|
|
<listitem>
|
|
<para>
|
|
lax (default) — the path engine implicitly adapts
|
|
the queried data to the specified path.
|
|
Any remaining structural errors are suppressed and converted
|
|
to empty SQL/JSON sequences.
|
|
</para>
|
|
</listitem>
|
|
<listitem>
|
|
<para>
|
|
strict — if a structural error occurs, an error is raised.
|
|
</para>
|
|
</listitem>
|
|
</itemizedlist>
|
|
|
|
<para>
|
|
The lax mode facilitates matching of a JSON document structure and path
|
|
expression if the JSON data does not conform to the expected schema.
|
|
If an operand does not match the requirements of a particular operation,
|
|
it can be automatically wrapped as an SQL/JSON array or unwrapped by
|
|
converting its elements into an SQL/JSON sequence before performing
|
|
this operation. Besides, comparison operators automatically unwrap their
|
|
operands in the lax mode, so you can compare SQL/JSON arrays
|
|
out-of-the-box. An array of size 1 is considered equal to its sole element.
|
|
Automatic unwrapping is not performed only when:
|
|
<itemizedlist>
|
|
<listitem>
|
|
<para>
|
|
The path expression contains <literal>type()</literal> or
|
|
<literal>size()</literal> methods that return the type
|
|
and the number of elements in the array, respectively.
|
|
</para>
|
|
</listitem>
|
|
<listitem>
|
|
<para>
|
|
The queried JSON data contain nested arrays. In this case, only
|
|
the outermost array is unwrapped, while all the inner arrays
|
|
remain unchanged. Thus, implicit unwrapping can only go one
|
|
level down within each path evaluation step.
|
|
</para>
|
|
</listitem>
|
|
</itemizedlist>
|
|
</para>
|
|
|
|
<para>
|
|
For example, when querying the GPS data listed above, you can
|
|
abstract from the fact that it stores an array of segments
|
|
when using the lax mode:
|
|
<programlisting>
|
|
'lax $.track.segments.location'
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
In the strict mode, the specified path must exactly match the structure of
|
|
the queried JSON document to return an SQL/JSON item, so using this
|
|
path expression will cause an error. To get the same result as in
|
|
the lax mode, you have to explicitly unwrap the
|
|
<literal>segments</literal> array:
|
|
<programlisting>
|
|
'strict $.track.segments[*].location'
|
|
</programlisting>
|
|
</para>
|
|
|
|
</sect3>
|
|
|
|
<sect3 id="jsonpath-regular-expressions">
|
|
<title>Regular Expressions</title>
|
|
|
|
<indexterm zone="jsonpath-regular-expressions">
|
|
<primary><literal>LIKE_REGEX</literal></primary>
|
|
<secondary>in SQL/JSON</secondary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
SQL/JSON path expressions allow matching text to a regular expression
|
|
with the <literal>like_regex</literal> filter. For example, the
|
|
following SQL/JSON path query would case-insensitively match all
|
|
strings in an array that start with an English vowel:
|
|
<programlisting>
|
|
'$[*] ? (@ like_regex "^[aeiou]" flag "i")'
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
The optional <literal>flag</literal> string may include one or more of
|
|
the characters
|
|
<literal>i</literal> for case-insensitive match,
|
|
<literal>m</literal> to allow <literal>^</literal>
|
|
and <literal>$</literal> to match at newlines,
|
|
<literal>s</literal> to allow <literal>.</literal> to match a newline,
|
|
and <literal>q</literal> to quote the whole pattern (reducing the
|
|
behavior to a simple substring match).
|
|
</para>
|
|
|
|
<para>
|
|
The SQL/JSON standard borrows its definition for regular expressions
|
|
from the <literal>LIKE_REGEX</literal> operator, which in turn uses the
|
|
XQuery standard. PostgreSQL does not currently support the
|
|
<literal>LIKE_REGEX</literal> operator. Therefore,
|
|
the <literal>like_regex</literal> filter is implemented using the
|
|
POSIX regular expression engine described in
|
|
<xref linkend="functions-posix-regexp"/>. This leads to various minor
|
|
discrepancies from standard SQL/JSON behavior, which are cataloged in
|
|
<xref linkend="posix-vs-xquery"/>.
|
|
Note, however, that the flag-letter incompatibilities described there
|
|
do not apply to SQL/JSON, as it translates the XQuery flag letters to
|
|
match what the POSIX engine expects.
|
|
</para>
|
|
|
|
<para>
|
|
Keep in mind that the pattern argument of <literal>like_regex</literal>
|
|
is a JSON path string literal, written according to the rules given in
|
|
<xref linkend="datatype-jsonpath"/>. This means in particular that any
|
|
backslashes you want to use in the regular expression must be doubled.
|
|
For example, to match strings that contain only digits:
|
|
<programlisting>
|
|
'$ ? (@ like_regex "^\\d+$")'
|
|
</programlisting>
|
|
</para>
|
|
|
|
</sect3>
|
|
|
|
<sect3 id="functions-sqljson-path-operators">
|
|
<title>SQL/JSON Path Operators and Methods</title>
|
|
|
|
<para>
|
|
<xref linkend="functions-sqljson-op-table"/> shows the operators and
|
|
methods available in <type>jsonpath</type>. <xref
|
|
linkend="functions-sqljson-filter-ex-table"/> shows the available filter
|
|
expression elements.
|
|
</para>
|
|
|
|
<table id="functions-sqljson-op-table">
|
|
<title><type>jsonpath</type> Operators and Methods</title>
|
|
<tgroup cols="5">
|
|
<thead>
|
|
<row>
|
|
<entry>Operator/Method</entry>
|
|
<entry>Description</entry>
|
|
<entry>Example JSON</entry>
|
|
<entry>Example Query</entry>
|
|
<entry>Result</entry>
|
|
</row>
|
|
</thead>
|
|
<tbody>
|
|
<row>
|
|
<entry><literal>+</literal> (unary)</entry>
|
|
<entry>Plus operator that iterates over the SQL/JSON sequence</entry>
|
|
<entry><literal>{"x": [2.85, -14.7, -9.4]}</literal></entry>
|
|
<entry><literal>+ $.x.floor()</literal></entry>
|
|
<entry><literal>2, -15, -10</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>-</literal> (unary)</entry>
|
|
<entry>Minus operator that iterates over the SQL/JSON sequence</entry>
|
|
<entry><literal>{"x": [2.85, -14.7, -9.4]}</literal></entry>
|
|
<entry><literal>- $.x.floor()</literal></entry>
|
|
<entry><literal>-2, 15, 10</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>+</literal> (binary)</entry>
|
|
<entry>Addition</entry>
|
|
<entry><literal>[2]</literal></entry>
|
|
<entry><literal>2 + $[0]</literal></entry>
|
|
<entry><literal>4</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>-</literal> (binary)</entry>
|
|
<entry>Subtraction</entry>
|
|
<entry><literal>[2]</literal></entry>
|
|
<entry><literal>4 - $[0]</literal></entry>
|
|
<entry><literal>2</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>*</literal></entry>
|
|
<entry>Multiplication</entry>
|
|
<entry><literal>[4]</literal></entry>
|
|
<entry><literal>2 * $[0]</literal></entry>
|
|
<entry><literal>8</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>/</literal></entry>
|
|
<entry>Division</entry>
|
|
<entry><literal>[8]</literal></entry>
|
|
<entry><literal>$[0] / 2</literal></entry>
|
|
<entry><literal>4</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>%</literal></entry>
|
|
<entry>Modulus</entry>
|
|
<entry><literal>[32]</literal></entry>
|
|
<entry><literal>$[0] % 10</literal></entry>
|
|
<entry><literal>2</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>type()</literal></entry>
|
|
<entry>Type of the SQL/JSON item</entry>
|
|
<entry><literal>[1, "2", {}]</literal></entry>
|
|
<entry><literal>$[*].type()</literal></entry>
|
|
<entry><literal>"number", "string", "object"</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>size()</literal></entry>
|
|
<entry>Size of the SQL/JSON item</entry>
|
|
<entry><literal>{"m": [11, 15]}</literal></entry>
|
|
<entry><literal>$.m.size()</literal></entry>
|
|
<entry><literal>2</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>double()</literal></entry>
|
|
<entry>Approximate floating-point number converted from an SQL/JSON number or a string</entry>
|
|
<entry><literal>{"len": "1.9"}</literal></entry>
|
|
<entry><literal>$.len.double() * 2</literal></entry>
|
|
<entry><literal>3.8</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>ceiling()</literal></entry>
|
|
<entry>Nearest integer greater than or equal to the SQL/JSON number</entry>
|
|
<entry><literal>{"h": 1.3}</literal></entry>
|
|
<entry><literal>$.h.ceiling()</literal></entry>
|
|
<entry><literal>2</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>floor()</literal></entry>
|
|
<entry>Nearest integer less than or equal to the SQL/JSON number</entry>
|
|
<entry><literal>{"h": 1.3}</literal></entry>
|
|
<entry><literal>$.h.floor()</literal></entry>
|
|
<entry><literal>1</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>abs()</literal></entry>
|
|
<entry>Absolute value of the SQL/JSON number</entry>
|
|
<entry><literal>{"z": -0.3}</literal></entry>
|
|
<entry><literal>$.z.abs()</literal></entry>
|
|
<entry><literal>0.3</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>keyvalue()</literal></entry>
|
|
<entry>
|
|
Sequence of object's key-value pairs represented as array of items
|
|
containing three fields (<literal>"key"</literal>,
|
|
<literal>"value"</literal>, and <literal>"id"</literal>).
|
|
<literal>"id"</literal> is a unique identifier of the object
|
|
key-value pair belongs to.
|
|
</entry>
|
|
<entry><literal>{"x": "20", "y": 32}</literal></entry>
|
|
<entry><literal>$.keyvalue()</literal></entry>
|
|
<entry><literal>{"key": "x", "value": "20", "id": 0}, {"key": "y", "value": 32, "id": 0}</literal></entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<table id="functions-sqljson-filter-ex-table">
|
|
<title><type>jsonpath</type> Filter Expression Elements</title>
|
|
<tgroup cols="5">
|
|
<thead>
|
|
<row>
|
|
<entry>Value/Predicate</entry>
|
|
<entry>Description</entry>
|
|
<entry>Example JSON</entry>
|
|
<entry>Example Query</entry>
|
|
<entry>Result</entry>
|
|
</row>
|
|
</thead>
|
|
<tbody>
|
|
<row>
|
|
<entry><literal>==</literal></entry>
|
|
<entry>Equality operator</entry>
|
|
<entry><literal>[1, 2, 1, 3]</literal></entry>
|
|
<entry><literal>$[*] ? (@ == 1)</literal></entry>
|
|
<entry><literal>1, 1</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>!=</literal></entry>
|
|
<entry>Non-equality operator</entry>
|
|
<entry><literal>[1, 2, 1, 3]</literal></entry>
|
|
<entry><literal>$[*] ? (@ != 1)</literal></entry>
|
|
<entry><literal>2, 3</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><></literal></entry>
|
|
<entry>Non-equality operator (same as <literal>!=</literal>)</entry>
|
|
<entry><literal>[1, 2, 1, 3]</literal></entry>
|
|
<entry><literal>$[*] ? (@ <> 1)</literal></entry>
|
|
<entry><literal>2, 3</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><</literal></entry>
|
|
<entry>Less-than operator</entry>
|
|
<entry><literal>[1, 2, 3]</literal></entry>
|
|
<entry><literal>$[*] ? (@ < 2)</literal></entry>
|
|
<entry><literal>1</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><=</literal></entry>
|
|
<entry>Less-than-or-equal-to operator</entry>
|
|
<entry><literal>[1, 2, 3]</literal></entry>
|
|
<entry><literal>$[*] ? (@ <= 2)</literal></entry>
|
|
<entry><literal>1, 2</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>></literal></entry>
|
|
<entry>Greater-than operator</entry>
|
|
<entry><literal>[1, 2, 3]</literal></entry>
|
|
<entry><literal>$[*] ? (@ > 2)</literal></entry>
|
|
<entry><literal>3</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>>=</literal></entry>
|
|
<entry>Greater-than-or-equal-to operator</entry>
|
|
<entry><literal>[1, 2, 3]</literal></entry>
|
|
<entry><literal>$[*] ? (@ >= 2)</literal></entry>
|
|
<entry><literal>2, 3</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>true</literal></entry>
|
|
<entry>Value used to perform comparison with JSON <literal>true</literal> literal</entry>
|
|
<entry><literal>[{"name": "John", "parent": false},
|
|
{"name": "Chris", "parent": true}]</literal></entry>
|
|
<entry><literal>$[*] ? (@.parent == true)</literal></entry>
|
|
<entry><literal>{"name": "Chris", "parent": true}</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>false</literal></entry>
|
|
<entry>Value used to perform comparison with JSON <literal>false</literal> literal</entry>
|
|
<entry><literal>[{"name": "John", "parent": false},
|
|
{"name": "Chris", "parent": true}]</literal></entry>
|
|
<entry><literal>$[*] ? (@.parent == false)</literal></entry>
|
|
<entry><literal>{"name": "John", "parent": false}</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>null</literal></entry>
|
|
<entry>Value used to perform comparison with JSON <literal>null</literal> value</entry>
|
|
<entry><literal>[{"name": "Mary", "job": null},
|
|
{"name": "Michael", "job": "driver"}]</literal></entry>
|
|
<entry><literal>$[*] ? (@.job == null) .name</literal></entry>
|
|
<entry><literal>"Mary"</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>&&</literal></entry>
|
|
<entry>Boolean AND</entry>
|
|
<entry><literal>[1, 3, 7]</literal></entry>
|
|
<entry><literal>$[*] ? (@ > 1 && @ < 5)</literal></entry>
|
|
<entry><literal>3</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>||</literal></entry>
|
|
<entry>Boolean OR</entry>
|
|
<entry><literal>[1, 3, 7]</literal></entry>
|
|
<entry><literal>$[*] ? (@ < 1 || @ > 5)</literal></entry>
|
|
<entry><literal>7</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>!</literal></entry>
|
|
<entry>Boolean NOT</entry>
|
|
<entry><literal>[1, 3, 7]</literal></entry>
|
|
<entry><literal>$[*] ? (!(@ < 5))</literal></entry>
|
|
<entry><literal>7</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>like_regex</literal></entry>
|
|
<entry>
|
|
Tests whether the first operand matches the regular expression
|
|
given by the second operand, optionally with modifications
|
|
described by a string of <literal>flag</literal> characters (see
|
|
<xref linkend="jsonpath-regular-expressions"/>)
|
|
</entry>
|
|
<entry><literal>["abc", "abd", "aBdC", "abdacb", "babc"]</literal></entry>
|
|
<entry><literal>$[*] ? (@ like_regex "^ab.*c" flag "i")</literal></entry>
|
|
<entry><literal>"abc", "aBdC", "abdacb"</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>starts with</literal></entry>
|
|
<entry>Tests whether the second operand is an initial substring of the first operand</entry>
|
|
<entry><literal>["John Smith", "Mary Stone", "Bob Johnson"]</literal></entry>
|
|
<entry><literal>$[*] ? (@ starts with "John")</literal></entry>
|
|
<entry><literal>"John Smith"</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>exists</literal></entry>
|
|
<entry>Tests whether a path expression matches at least one SQL/JSON item</entry>
|
|
<entry><literal>{"x": [1, 2], "y": [2, 4]}</literal></entry>
|
|
<entry><literal>strict $.* ? (exists (@ ? (@[*] > 2)))</literal></entry>
|
|
<entry><literal>2, 4</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>is unknown</literal></entry>
|
|
<entry>Tests whether a Boolean condition is <literal>unknown</literal></entry>
|
|
<entry><literal>[-1, 2, 7, "infinity"]</literal></entry>
|
|
<entry><literal>$[*] ? ((@ > 0) is unknown)</literal></entry>
|
|
<entry><literal>"infinity"</literal></entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
</sect3>
|
|
</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 functions for operating on <firstterm>sequence
|
|
objects</firstterm>, also called sequence generators or just sequences.
|
|
Sequence objects are special single-row tables created with <xref
|
|
linkend="sql-createsequence"/>.
|
|
Sequence objects are commonly 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</type> argument, which is simply the OID of the sequence in the
|
|
<structname>pg_class</structname> system catalog. You do not have to look up the
|
|
OID by hand, however, since the <type>regclass</type> 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></lineannotation>
|
|
nextval('FOO') <lineannotation>operates on sequence <literal>foo</literal></lineannotation>
|
|
nextval('"Foo"') <lineannotation>operates on sequence <literal>Foo</literal></lineannotation>
|
|
</programlisting>
|
|
The sequence name can be schema-qualified if necessary:
|
|
<programlisting>
|
|
nextval('myschema.foo') <lineannotation>operates on <literal>myschema.foo</literal></lineannotation>
|
|
nextval('"myschema".foo') <lineannotation>same as above</lineannotation>
|
|
nextval('foo') <lineannotation>searches search path for <literal>foo</literal></lineannotation>
|
|
</programlisting>
|
|
See <xref linkend="datatype-oid"/> for more information about
|
|
<type>regclass</type>.
|
|
</para>
|
|
|
|
<note>
|
|
<para>
|
|
Before <productname>PostgreSQL</productname> 8.1, the arguments of the
|
|
sequence functions were of type <type>text</type>, not <type>regclass</type>, and
|
|
the above-described conversion from a text string to an OID value would
|
|
happen at run time during each call. For backward compatibility, this
|
|
facility still exists, but internally it is now handled as an implicit
|
|
coercion from <type>text</type> to <type>regclass</type> 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</type>.
|
|
Since this is really just an OID, it will track the originally
|
|
identified sequence despite later renaming, schema reassignment,
|
|
etc. This <quote>early binding</quote> behavior is usually desirable for
|
|
sequence references in column defaults and views. But sometimes you might
|
|
want <quote>late binding</quote> where the sequence reference is resolved
|
|
at run time. To get late-binding behavior, force the constant to be
|
|
stored as a <type>text</type> constant instead of <type>regclass</type>:
|
|
<programlisting>
|
|
nextval('foo'::text) <lineannotation><literal>foo</literal> is looked up at runtime</lineannotation>
|
|
</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>
|
|
|
|
<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 and will not be returned again. This is true even if the
|
|
surrounding transaction later aborts, or if the calling query ends
|
|
up not using the value. For example an <command>INSERT</command> with
|
|
an <literal>ON CONFLICT</literal> clause will compute the to-be-inserted
|
|
tuple, including doing any required <function>nextval</function>
|
|
calls, before detecting any conflict that would cause it to follow
|
|
the <literal>ON CONFLICT</literal> rule instead. Such cases will leave
|
|
unused <quote>holes</quote> in the sequence of assigned values.
|
|
Thus, <productname>PostgreSQL</productname> sequence objects <emphasis>cannot
|
|
be used to obtain <quote>gapless</quote> sequences</emphasis>.
|
|
</para>
|
|
</important>
|
|
|
|
<para>
|
|
This function requires <literal>USAGE</literal>
|
|
or <literal>UPDATE</literal> privilege on the sequence.
|
|
</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>
|
|
|
|
<para>
|
|
This function requires <literal>USAGE</literal>
|
|
or <literal>SELECT</literal> privilege on the sequence.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><function>lastval</function></term>
|
|
<listitem>
|
|
<para>
|
|
Return the value most recently returned by
|
|
<function>nextval</function> in the current session. This function is
|
|
identical to <function>currval</function>, except that instead
|
|
of taking the sequence name as an argument it refers to whichever
|
|
sequence <function>nextval</function> was most recently applied to
|
|
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>
|
|
|
|
<para>
|
|
This function requires <literal>USAGE</literal>
|
|
or <literal>SELECT</literal> privilege on the last used sequence.
|
|
</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</function> 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</literal> 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</function> is not changed in this case. For example,
|
|
|
|
<screen>
|
|
SELECT setval('foo', 42); <lineannotation>Next <function>nextval</function> will return 43</lineannotation>
|
|
SELECT setval('foo', 42, true); <lineannotation>Same as above</lineannotation>
|
|
SELECT setval('foo', 42, false); <lineannotation>Next <function>nextval</function> will return 42</lineannotation>
|
|
</screen>
|
|
|
|
The result returned by <function>setval</function> is just the value of its
|
|
second argument.
|
|
</para>
|
|
<important>
|
|
<para>
|
|
Because sequences are non-transactional, changes made by
|
|
<function>setval</function> are not undone if the transaction rolls
|
|
back.
|
|
</para>
|
|
</important>
|
|
|
|
<para>
|
|
This function requires <literal>UPDATE</literal> privilege on the
|
|
sequence.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
</variablelist>
|
|
</para>
|
|
|
|
</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 server-side function
|
|
in a more expressive programming language.
|
|
</para>
|
|
</tip>
|
|
|
|
<note>
|
|
<para>
|
|
Although <token>COALESCE</token>, <token>GREATEST</token>, and
|
|
<token>LEAST</token> are syntactically similar to functions, they are
|
|
not ordinary functions, and thus cannot be used with explicit
|
|
<token>VARIADIC</token> array arguments.
|
|
</para>
|
|
</note>
|
|
|
|
<sect2 id="functions-case">
|
|
<title><literal>CASE</literal></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</token> 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</quote> 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>
|
|
|
|
<note>
|
|
<para>
|
|
As described in <xref linkend="syntax-express-eval"/>, there are various
|
|
situations in which subexpressions of an expression are evaluated at
|
|
different times, so that the principle that <quote><token>CASE</token>
|
|
evaluates only necessary subexpressions</quote> is not ironclad. For
|
|
example a constant <literal>1/0</literal> subexpression will usually result in
|
|
a division-by-zero failure at planning time, even if it's within
|
|
a <token>CASE</token> arm that would never be entered at run time.
|
|
</para>
|
|
</note>
|
|
</sect2>
|
|
|
|
<sect2 id="functions-coalesce-nvl-ifnull">
|
|
<title><literal>COALESCE</literal></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>
|
|
This returns <varname>description</varname> if it is not null, otherwise
|
|
<varname>short_description</varname> if it is not null, otherwise <literal>(none)</literal>.
|
|
</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</function> and <function>IFNULL</function>, which are used in some other
|
|
database systems.
|
|
</para>
|
|
</sect2>
|
|
|
|
<sect2 id="functions-nullif">
|
|
<title><literal>NULLIF</literal></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)</literal>,
|
|
null is returned, otherwise the value of <literal>value</literal>
|
|
is returned.
|
|
</para>
|
|
|
|
</sect2>
|
|
|
|
<sect2 id="functions-greatest-least">
|
|
<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</function> and <function>LEAST</function> 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</function> and <function>LEAST</function> 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,3]</literal></entry>
|
|
<entry><literal>t</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal><@</literal> </entry>
|
|
<entry>is contained by</entry>
|
|
<entry><literal>ARRAY[2,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>
|
|
The array ordering operators (<literal><</literal>,
|
|
<literal>>=</literal>, etc) compare the array contents
|
|
element-by-element, using the default B-tree comparison function for
|
|
the element data type, and sort based on the first difference.
|
|
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</productname> 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>
|
|
The array containment operators (<literal><@</literal>
|
|
and <literal>@></literal>) consider one array to be contained in
|
|
another one if each of its elements appears in the other one.
|
|
Duplicates are not treated specially, thus <literal>ARRAY[1]</literal>
|
|
and <literal>ARRAY[1,1]</literal> are each considered to contain the
|
|
other.
|
|
</para>
|
|
|
|
<para>
|
|
See <xref linkend="arrays"/> for more details about array operator
|
|
behavior. See <xref linkend="indexes-types"/> for more details about
|
|
which operators support indexed operations.
|
|
</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_position</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>array_positions</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>array_prepend</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>array_remove</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>array_replace</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>array_to_string</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>array_upper</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>cardinality</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_position</function>(<type>anyarray</type>, <type>anyelement</type> <optional>, <type>int</type></optional>)
|
|
</literal>
|
|
</entry>
|
|
<entry><type>int</type></entry>
|
|
<entry>returns the subscript of the first occurrence of the second
|
|
argument in the array, starting at the element indicated by the third
|
|
argument or at the first element (array must be one-dimensional)</entry>
|
|
<entry><literal>array_position(ARRAY['sun','mon','tue','wed','thu','fri','sat'], 'mon')</literal></entry>
|
|
<entry><literal>2</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal>
|
|
<function>array_positions</function>(<type>anyarray</type>, <type>anyelement</type>)
|
|
</literal>
|
|
</entry>
|
|
<entry><type>int[]</type></entry>
|
|
<entry>returns an array of subscripts of all occurrences of the second
|
|
argument in the array given as first argument (array must be
|
|
one-dimensional)</entry>
|
|
<entry><literal>array_positions(ARRAY['A','A','B','A'], 'A')</literal></entry>
|
|
<entry><literal>{1,2,4}</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_remove</function>(<type>anyarray</type>, <type>anyelement</type>)
|
|
</literal>
|
|
</entry>
|
|
<entry><type>anyarray</type></entry>
|
|
<entry>remove all elements equal to the given value from the array
|
|
(array must be one-dimensional)</entry>
|
|
<entry><literal>array_remove(ARRAY[1,2,3,2], 2)</literal></entry>
|
|
<entry><literal>{1,3}</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal>
|
|
<function>array_replace</function>(<type>anyarray</type>, <type>anyelement</type>, <type>anyelement</type>)
|
|
</literal>
|
|
</entry>
|
|
<entry><type>anyarray</type></entry>
|
|
<entry>replace each array element equal to the given value with a new value</entry>
|
|
<entry><literal>array_replace(ARRAY[1,2,5,4], 5, 3)</literal></entry>
|
|
<entry><literal>{1,2,3,4}</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>cardinality</function>(<type>anyarray</type>)
|
|
</literal>
|
|
</entry>
|
|
<entry><type>int</type></entry>
|
|
<entry>returns the total number of elements in the array, or 0 if the array is empty</entry>
|
|
<entry><literal>cardinality(ARRAY[[1,2],[3,4]])</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>
|
|
<row>
|
|
<entry>
|
|
<literal>
|
|
<function>unnest</function>(<type>anyarray</type>, <type>anyarray</type> [, ...])
|
|
</literal>
|
|
</entry>
|
|
<entry><type>setof anyelement, anyelement [, ...]</type></entry>
|
|
<entry>expand multiple arrays (possibly of different types) to a set
|
|
of rows. This is only allowed in the FROM clause; see
|
|
<xref linkend="queries-tablefunctions"/></entry>
|
|
<entry><literal>unnest(ARRAY[1,2],ARRAY['foo','bar','baz'])</literal></entry>
|
|
<entry><literallayout class="monospaced">1 foo
|
|
2 bar
|
|
NULL baz</literallayout>(3 rows)</entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
In <function>array_position</function> and <function>array_positions</function>,
|
|
each array element is compared to the searched value using
|
|
<literal>IS NOT DISTINCT FROM</literal> semantics.
|
|
</para>
|
|
|
|
<para>
|
|
In <function>array_position</function>, <literal>NULL</literal> is returned
|
|
if the value is not found.
|
|
</para>
|
|
|
|
<para>
|
|
In <function>array_positions</function>, <literal>NULL</literal> is returned
|
|
only if the array is <literal>NULL</literal>; if the value is not found in
|
|
the array, an empty array is returned instead.
|
|
</para>
|
|
|
|
<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</function>
|
|
from pre-9.1 versions of <productname>PostgreSQL</productname>.
|
|
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-range">
|
|
<title>Range Functions and Operators</title>
|
|
|
|
<para>
|
|
See <xref linkend="rangetypes"/> for an overview of range types.
|
|
</para>
|
|
|
|
<para>
|
|
<xref linkend="range-operators-table"/> shows the operators
|
|
available for range types.
|
|
</para>
|
|
|
|
<table id="range-operators-table">
|
|
<title>Range 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>int4range(1,5) = '[1,4]'::int4range</literal></entry>
|
|
<entry><literal>t</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal><></literal> </entry>
|
|
<entry>not equal</entry>
|
|
<entry><literal>numrange(1.1,2.2) <> numrange(1.1,2.3)</literal></entry>
|
|
<entry><literal>t</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal><</literal> </entry>
|
|
<entry>less than</entry>
|
|
<entry><literal>int4range(1,10) < int4range(2,3)</literal></entry>
|
|
<entry><literal>t</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>></literal> </entry>
|
|
<entry>greater than</entry>
|
|
<entry><literal>int4range(1,10) > int4range(1,5)</literal></entry>
|
|
<entry><literal>t</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal><=</literal> </entry>
|
|
<entry>less than or equal</entry>
|
|
<entry><literal>numrange(1.1,2.2) <= numrange(1.1,2.2)</literal></entry>
|
|
<entry><literal>t</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>>=</literal> </entry>
|
|
<entry>greater than or equal</entry>
|
|
<entry><literal>numrange(1.1,2.2) >= numrange(1.1,2.0)</literal></entry>
|
|
<entry><literal>t</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>@></literal> </entry>
|
|
<entry>contains range</entry>
|
|
<entry><literal>int4range(2,4) @> int4range(2,3)</literal></entry>
|
|
<entry><literal>t</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>@></literal> </entry>
|
|
<entry>contains element</entry>
|
|
<entry><literal>'[2011-01-01,2011-03-01)'::tsrange @> '2011-01-10'::timestamp</literal></entry>
|
|
<entry><literal>t</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal><@</literal> </entry>
|
|
<entry>range is contained by</entry>
|
|
<entry><literal>int4range(2,4) <@ int4range(1,7)</literal></entry>
|
|
<entry><literal>t</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal><@</literal> </entry>
|
|
<entry>element is contained by</entry>
|
|
<entry><literal>42 <@ int4range(1,7)</literal></entry>
|
|
<entry><literal>f</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>&&</literal> </entry>
|
|
<entry>overlap (have points in common)</entry>
|
|
<entry><literal>int8range(3,7) && int8range(4,12)</literal></entry>
|
|
<entry><literal>t</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal><<</literal> </entry>
|
|
<entry>strictly left of</entry>
|
|
<entry><literal>int8range(1,10) << int8range(100,110)</literal></entry>
|
|
<entry><literal>t</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>>></literal> </entry>
|
|
<entry>strictly right of</entry>
|
|
<entry><literal>int8range(50,60) >> int8range(20,30)</literal></entry>
|
|
<entry><literal>t</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>&<</literal> </entry>
|
|
<entry>does not extend to the right of</entry>
|
|
<entry><literal>int8range(1,20) &< int8range(18,20)</literal></entry>
|
|
<entry><literal>t</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>&></literal> </entry>
|
|
<entry>does not extend to the left of</entry>
|
|
<entry><literal>int8range(7,20) &> int8range(5,10)</literal></entry>
|
|
<entry><literal>t</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>-|-</literal> </entry>
|
|
<entry>is adjacent to</entry>
|
|
<entry><literal>numrange(1.1,2.2) -|- numrange(2.2,3.3)</literal></entry>
|
|
<entry><literal>t</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>+</literal> </entry>
|
|
<entry>union</entry>
|
|
<entry><literal>numrange(5,15) + numrange(10,20)</literal></entry>
|
|
<entry><literal>[5,20)</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>*</literal> </entry>
|
|
<entry>intersection</entry>
|
|
<entry><literal>int8range(5,15) * int8range(10,20)</literal></entry>
|
|
<entry><literal>[10,15)</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>-</literal> </entry>
|
|
<entry>difference</entry>
|
|
<entry><literal>int8range(5,15) - int8range(10,20)</literal></entry>
|
|
<entry><literal>[5,10)</literal></entry>
|
|
</row>
|
|
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
The simple comparison operators <literal><</literal>,
|
|
<literal>></literal>, <literal><=</literal>, and
|
|
<literal>>=</literal> compare the lower bounds first, and only if those
|
|
are equal, compare the upper bounds. These comparisons are not usually
|
|
very useful for ranges, but are provided to allow B-tree indexes to be
|
|
constructed on ranges.
|
|
</para>
|
|
|
|
<para>
|
|
The left-of/right-of/adjacent operators always return false when an empty
|
|
range is involved; that is, an empty range is not considered to be either
|
|
before or after any other range.
|
|
</para>
|
|
|
|
<para>
|
|
The union and difference operators will fail if the resulting range would
|
|
need to contain two disjoint sub-ranges, as such a range cannot be
|
|
represented.
|
|
</para>
|
|
|
|
<para>
|
|
<xref linkend="range-functions-table"/> shows the functions
|
|
available for use with range types.
|
|
</para>
|
|
|
|
<indexterm>
|
|
<primary>lower</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>upper</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>isempty</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>lower_inc</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>upper_inc</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>lower_inf</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>upper_inf</primary>
|
|
</indexterm>
|
|
|
|
<table id="range-functions-table">
|
|
<title>Range 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>lower</function>(<type>anyrange</type>)
|
|
</literal>
|
|
</entry>
|
|
<entry>range's element type</entry>
|
|
<entry>lower bound of range</entry>
|
|
<entry><literal>lower(numrange(1.1,2.2))</literal></entry>
|
|
<entry><literal>1.1</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal>
|
|
<function>upper</function>(<type>anyrange</type>)
|
|
</literal>
|
|
</entry>
|
|
<entry>range's element type</entry>
|
|
<entry>upper bound of range</entry>
|
|
<entry><literal>upper(numrange(1.1,2.2))</literal></entry>
|
|
<entry><literal>2.2</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal>
|
|
<function>isempty</function>(<type>anyrange</type>)
|
|
</literal>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>is the range empty?</entry>
|
|
<entry><literal>isempty(numrange(1.1,2.2))</literal></entry>
|
|
<entry><literal>false</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal>
|
|
<function>lower_inc</function>(<type>anyrange</type>)
|
|
</literal>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>is the lower bound inclusive?</entry>
|
|
<entry><literal>lower_inc(numrange(1.1,2.2))</literal></entry>
|
|
<entry><literal>true</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal>
|
|
<function>upper_inc</function>(<type>anyrange</type>)
|
|
</literal>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>is the upper bound inclusive?</entry>
|
|
<entry><literal>upper_inc(numrange(1.1,2.2))</literal></entry>
|
|
<entry><literal>false</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal>
|
|
<function>lower_inf</function>(<type>anyrange</type>)
|
|
</literal>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>is the lower bound infinite?</entry>
|
|
<entry><literal>lower_inf('(,)'::daterange)</literal></entry>
|
|
<entry><literal>true</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal>
|
|
<function>upper_inf</function>(<type>anyrange</type>)
|
|
</literal>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>is the upper bound infinite?</entry>
|
|
<entry><literal>upper_inf('(,)'::daterange)</literal></entry>
|
|
<entry><literal>true</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal>
|
|
<function>range_merge</function>(<type>anyrange</type>, <type>anyrange</type>)
|
|
</literal>
|
|
</entry>
|
|
<entry><type>anyrange</type></entry>
|
|
<entry>the smallest range which includes both of the given ranges</entry>
|
|
<entry><literal>range_merge('[1,2)'::int4range, '[3,4)'::int4range)</literal></entry>
|
|
<entry><literal>[1,4)</literal></entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
The <function>lower</function> and <function>upper</function> functions return null
|
|
if the range is empty or the requested bound is infinite.
|
|
The <function>lower_inc</function>, <function>upper_inc</function>,
|
|
<function>lower_inf</function>, and <function>upper_inf</function>
|
|
functions all return false for an empty range.
|
|
</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 general-purpose aggregate
|
|
functions are listed in <xref linkend="functions-aggregate-table"/>
|
|
and statistical aggregates in <xref
|
|
linkend="functions-aggregate-statistics-table"/>.
|
|
The built-in within-group ordered-set aggregate functions
|
|
are listed in <xref linkend="functions-orderedset-table"/>
|
|
while the built-in within-group hypothetical-set ones are in <xref
|
|
linkend="functions-hypothetical-table"/>. Grouping operations,
|
|
which are closely related to aggregate functions, are listed in
|
|
<xref linkend="functions-grouping-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="5">
|
|
<thead>
|
|
<row>
|
|
<entry>Function</entry>
|
|
<entry>Argument Type(s)</entry>
|
|
<entry>Return Type</entry>
|
|
<entry>Partial Mode</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 non-array type
|
|
</entry>
|
|
<entry>
|
|
array of the argument type
|
|
</entry>
|
|
<entry>No</entry>
|
|
<entry>input values, including nulls, concatenated into an array</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<function>array_agg(<replaceable class="parameter">expression</replaceable>)</function>
|
|
</entry>
|
|
<entry>
|
|
any array type
|
|
</entry>
|
|
<entry>
|
|
same as argument data type
|
|
</entry>
|
|
<entry>No</entry>
|
|
<entry>input arrays concatenated into array of one higher dimension
|
|
(inputs must all have same dimensionality,
|
|
and cannot be empty or null)</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>Yes</entry>
|
|
<entry>the average (arithmetic mean) of all non-null 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>Yes</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>Yes</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>Yes</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>Yes</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>Yes</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>Yes</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>Yes</entry>
|
|
<entry>equivalent to <function>bool_and</function></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>json_agg</primary>
|
|
</indexterm>
|
|
<function>json_agg(<replaceable class="parameter">expression</replaceable>)</function>
|
|
</entry>
|
|
<entry>
|
|
<type>any</type>
|
|
</entry>
|
|
<entry>
|
|
<type>json</type>
|
|
</entry>
|
|
<entry>No</entry>
|
|
<entry>aggregates values, including nulls, as a JSON array</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>jsonb_agg</primary>
|
|
</indexterm>
|
|
<function>jsonb_agg(<replaceable class="parameter">expression</replaceable>)</function>
|
|
</entry>
|
|
<entry>
|
|
<type>any</type>
|
|
</entry>
|
|
<entry>
|
|
<type>jsonb</type>
|
|
</entry>
|
|
<entry>No</entry>
|
|
<entry>aggregates values, including nulls, as a JSON array</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>json_object_agg</primary>
|
|
</indexterm>
|
|
<function>json_object_agg(<replaceable class="parameter">name</replaceable>, <replaceable class="parameter">value</replaceable>)</function>
|
|
</entry>
|
|
<entry>
|
|
<type>(any, any)</type>
|
|
</entry>
|
|
<entry>
|
|
<type>json</type>
|
|
</entry>
|
|
<entry>No</entry>
|
|
<entry>aggregates name/value pairs as a JSON object; values can be
|
|
null, but not names</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>jsonb_object_agg</primary>
|
|
</indexterm>
|
|
<function>jsonb_object_agg(<replaceable class="parameter">name</replaceable>, <replaceable class="parameter">value</replaceable>)</function>
|
|
</entry>
|
|
<entry>
|
|
<type>(any, any)</type>
|
|
</entry>
|
|
<entry>
|
|
<type>jsonb</type>
|
|
</entry>
|
|
<entry>No</entry>
|
|
<entry>aggregates name/value pairs as a JSON object; values can be
|
|
null, but not names</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>max</primary>
|
|
</indexterm>
|
|
<function>max(<replaceable class="parameter">expression</replaceable>)</function>
|
|
</entry>
|
|
<entry>any numeric, string, date/time, network, or enum type,
|
|
or arrays of these types</entry>
|
|
<entry>same as argument type</entry>
|
|
<entry>Yes</entry>
|
|
<entry>
|
|
maximum value of <replaceable
|
|
class="parameter">expression</replaceable> across all non-null input
|
|
values
|
|
</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>min</primary>
|
|
</indexterm>
|
|
<function>min(<replaceable class="parameter">expression</replaceable>)</function>
|
|
</entry>
|
|
<entry>any numeric, string, date/time, network, or enum type,
|
|
or arrays of these types</entry>
|
|
<entry>same as argument type</entry>
|
|
<entry>Yes</entry>
|
|
<entry>
|
|
minimum value of <replaceable
|
|
class="parameter">expression</replaceable> across all non-null 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>) or (<type>bytea</type>, <type>bytea</type>)
|
|
</entry>
|
|
<entry>
|
|
same as argument types
|
|
</entry>
|
|
<entry>No</entry>
|
|
<entry>non-null 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>,
|
|
<type>interval</type>, or <type>money</type>
|
|
</entry>
|
|
<entry>
|
|
<type>bigint</type> for <type>smallint</type> or
|
|
<type>int</type> arguments, <type>numeric</type> for
|
|
<type>bigint</type> arguments, otherwise the same as the
|
|
argument data type
|
|
</entry>
|
|
<entry>Yes</entry>
|
|
<entry>sum of <replaceable class="parameter">expression</replaceable>
|
|
across all non-null 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>No</entry>
|
|
<entry>concatenation of non-null 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>
|
|
|
|
<para>
|
|
Aggregate functions which support <firstterm>Partial Mode</firstterm>
|
|
are eligible to participate in various optimizations, such as parallel
|
|
aggregation.
|
|
</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 require effort proportional to the size of the table:
|
|
<productname>PostgreSQL</productname> will need to scan either the
|
|
entire table or the entirety of an index which includes all rows in
|
|
the table.
|
|
</para>
|
|
</note>
|
|
|
|
<para>
|
|
The aggregate functions <function>array_agg</function>,
|
|
<function>json_agg</function>, <function>jsonb_agg</function>,
|
|
<function>json_object_agg</function>, <function>jsonb_object_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</literal> 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>
|
|
|
|
Beware that this approach can fail if the outer query level contains
|
|
additional processing, such as a join, because that might cause the
|
|
subquery's output to be reordered before the aggregate is computed.
|
|
</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="5">
|
|
<thead>
|
|
<row>
|
|
<entry>Function</entry>
|
|
<entry>Argument Type</entry>
|
|
<entry>Return Type</entry>
|
|
<entry>Partial Mode</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>Yes</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>Yes</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>Yes</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>Yes</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>Yes</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>Yes</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>Yes</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>Yes</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>Yes</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>Yes</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>Yes</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>Yes</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>Yes</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>Yes</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>Yes</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>Yes</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>Yes</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>Yes</entry>
|
|
<entry>sample variance of the input values (square of the sample standard deviation)</entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
<xref linkend="functions-orderedset-table"/> shows some
|
|
aggregate functions that use the <firstterm>ordered-set aggregate</firstterm>
|
|
syntax. These functions are sometimes referred to as <quote>inverse
|
|
distribution</quote> functions.
|
|
</para>
|
|
|
|
<indexterm>
|
|
<primary>ordered-set aggregate</primary>
|
|
<secondary>built-in</secondary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>inverse distribution</primary>
|
|
</indexterm>
|
|
|
|
<table id="functions-orderedset-table">
|
|
<title>Ordered-Set Aggregate Functions</title>
|
|
|
|
<tgroup cols="6">
|
|
<thead>
|
|
<row>
|
|
<entry>Function</entry>
|
|
<entry>Direct Argument Type(s)</entry>
|
|
<entry>Aggregated Argument Type(s)</entry>
|
|
<entry>Return Type</entry>
|
|
<entry>Partial Mode</entry>
|
|
<entry>Description</entry>
|
|
</row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>mode</primary>
|
|
<secondary>statistical</secondary>
|
|
</indexterm>
|
|
<function>mode() WITHIN GROUP (ORDER BY <replaceable class="parameter">sort_expression</replaceable>)</function>
|
|
</entry>
|
|
<entry>
|
|
</entry>
|
|
<entry>
|
|
any sortable type
|
|
</entry>
|
|
<entry>
|
|
same as sort expression
|
|
</entry>
|
|
<entry>No</entry>
|
|
<entry>
|
|
returns the most frequent input value (arbitrarily choosing the first
|
|
one if there are multiple equally-frequent results)
|
|
</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>percentile</primary>
|
|
<secondary>continuous</secondary>
|
|
</indexterm>
|
|
<function>percentile_cont(<replaceable class="parameter">fraction</replaceable>) WITHIN GROUP (ORDER BY <replaceable class="parameter">sort_expression</replaceable>)</function>
|
|
</entry>
|
|
<entry>
|
|
<type>double precision</type>
|
|
</entry>
|
|
<entry>
|
|
<type>double precision</type> or <type>interval</type>
|
|
</entry>
|
|
<entry>
|
|
same as sort expression
|
|
</entry>
|
|
<entry>No</entry>
|
|
<entry>
|
|
continuous percentile: returns a value corresponding to the specified
|
|
fraction in the ordering, interpolating between adjacent input items if
|
|
needed
|
|
</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<function>percentile_cont(<replaceable class="parameter">fractions</replaceable>) WITHIN GROUP (ORDER BY <replaceable class="parameter">sort_expression</replaceable>)</function>
|
|
</entry>
|
|
<entry>
|
|
<type>double precision[]</type>
|
|
</entry>
|
|
<entry>
|
|
<type>double precision</type> or <type>interval</type>
|
|
</entry>
|
|
<entry>
|
|
array of sort expression's type
|
|
</entry>
|
|
<entry>No</entry>
|
|
<entry>
|
|
multiple continuous percentile: returns an array of results matching
|
|
the shape of the <replaceable>fractions</replaceable> parameter, with each
|
|
non-null element replaced by the value corresponding to that percentile
|
|
</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>percentile</primary>
|
|
<secondary>discrete</secondary>
|
|
</indexterm>
|
|
<function>percentile_disc(<replaceable class="parameter">fraction</replaceable>) WITHIN GROUP (ORDER BY <replaceable class="parameter">sort_expression</replaceable>)</function>
|
|
</entry>
|
|
<entry>
|
|
<type>double precision</type>
|
|
</entry>
|
|
<entry>
|
|
any sortable type
|
|
</entry>
|
|
<entry>
|
|
same as sort expression
|
|
</entry>
|
|
<entry>No</entry>
|
|
<entry>
|
|
discrete percentile: returns the first input value whose position in
|
|
the ordering equals or exceeds the specified fraction
|
|
</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<function>percentile_disc(<replaceable class="parameter">fractions</replaceable>) WITHIN GROUP (ORDER BY <replaceable class="parameter">sort_expression</replaceable>)</function>
|
|
</entry>
|
|
<entry>
|
|
<type>double precision[]</type>
|
|
</entry>
|
|
<entry>
|
|
any sortable type
|
|
</entry>
|
|
<entry>
|
|
array of sort expression's type
|
|
</entry>
|
|
<entry>No</entry>
|
|
<entry>
|
|
multiple discrete percentile: returns an array of results matching the
|
|
shape of the <replaceable>fractions</replaceable> parameter, with each non-null
|
|
element replaced by the input value corresponding to that percentile
|
|
</entry>
|
|
</row>
|
|
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
All the aggregates listed in <xref linkend="functions-orderedset-table"/>
|
|
ignore null values in their sorted input. For those that take
|
|
a <replaceable>fraction</replaceable> parameter, the fraction value must be
|
|
between 0 and 1; an error is thrown if not. However, a null fraction value
|
|
simply produces a null result.
|
|
</para>
|
|
|
|
<indexterm>
|
|
<primary>hypothetical-set aggregate</primary>
|
|
<secondary>built-in</secondary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
Each of the aggregates listed in
|
|
<xref linkend="functions-hypothetical-table"/> is associated with a
|
|
window function of the same name defined in
|
|
<xref linkend="functions-window"/>. In each case, the aggregate result
|
|
is the value that the associated window function would have
|
|
returned for the <quote>hypothetical</quote> row constructed from
|
|
<replaceable>args</replaceable>, if such a row had been added to the sorted
|
|
group of rows computed from the <replaceable>sorted_args</replaceable>.
|
|
</para>
|
|
|
|
<table id="functions-hypothetical-table">
|
|
<title>Hypothetical-Set Aggregate Functions</title>
|
|
|
|
<tgroup cols="6">
|
|
<thead>
|
|
<row>
|
|
<entry>Function</entry>
|
|
<entry>Direct Argument Type(s)</entry>
|
|
<entry>Aggregated Argument Type(s)</entry>
|
|
<entry>Return Type</entry>
|
|
<entry>Partial Mode</entry>
|
|
<entry>Description</entry>
|
|
</row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>rank</primary>
|
|
<secondary>hypothetical</secondary>
|
|
</indexterm>
|
|
<function>rank(<replaceable class="parameter">args</replaceable>) WITHIN GROUP (ORDER BY <replaceable class="parameter">sorted_args</replaceable>)</function>
|
|
</entry>
|
|
<entry>
|
|
<literal>VARIADIC</literal> <type>"any"</type>
|
|
</entry>
|
|
<entry>
|
|
<literal>VARIADIC</literal> <type>"any"</type>
|
|
</entry>
|
|
<entry>
|
|
<type>bigint</type>
|
|
</entry>
|
|
<entry>No</entry>
|
|
<entry>
|
|
rank of the hypothetical row, with gaps for duplicate rows
|
|
</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>dense_rank</primary>
|
|
<secondary>hypothetical</secondary>
|
|
</indexterm>
|
|
<function>dense_rank(<replaceable class="parameter">args</replaceable>) WITHIN GROUP (ORDER BY <replaceable class="parameter">sorted_args</replaceable>)</function>
|
|
</entry>
|
|
<entry>
|
|
<literal>VARIADIC</literal> <type>"any"</type>
|
|
</entry>
|
|
<entry>
|
|
<literal>VARIADIC</literal> <type>"any"</type>
|
|
</entry>
|
|
<entry>
|
|
<type>bigint</type>
|
|
</entry>
|
|
<entry>No</entry>
|
|
<entry>
|
|
rank of the hypothetical row, without gaps
|
|
</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>percent_rank</primary>
|
|
<secondary>hypothetical</secondary>
|
|
</indexterm>
|
|
<function>percent_rank(<replaceable class="parameter">args</replaceable>) WITHIN GROUP (ORDER BY <replaceable class="parameter">sorted_args</replaceable>)</function>
|
|
</entry>
|
|
<entry>
|
|
<literal>VARIADIC</literal> <type>"any"</type>
|
|
</entry>
|
|
<entry>
|
|
<literal>VARIADIC</literal> <type>"any"</type>
|
|
</entry>
|
|
<entry>
|
|
<type>double precision</type>
|
|
</entry>
|
|
<entry>No</entry>
|
|
<entry>
|
|
relative rank of the hypothetical row, ranging from 0 to 1
|
|
</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>cume_dist</primary>
|
|
<secondary>hypothetical</secondary>
|
|
</indexterm>
|
|
<function>cume_dist(<replaceable class="parameter">args</replaceable>) WITHIN GROUP (ORDER BY <replaceable class="parameter">sorted_args</replaceable>)</function>
|
|
</entry>
|
|
<entry>
|
|
<literal>VARIADIC</literal> <type>"any"</type>
|
|
</entry>
|
|
<entry>
|
|
<literal>VARIADIC</literal> <type>"any"</type>
|
|
</entry>
|
|
<entry>
|
|
<type>double precision</type>
|
|
</entry>
|
|
<entry>No</entry>
|
|
<entry>
|
|
relative rank of the hypothetical row, ranging from
|
|
1/<replaceable>N</replaceable> to 1
|
|
</entry>
|
|
</row>
|
|
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
For each of these hypothetical-set aggregates, the list of direct arguments
|
|
given in <replaceable>args</replaceable> must match the number and types of
|
|
the aggregated arguments given in <replaceable>sorted_args</replaceable>.
|
|
Unlike most built-in aggregates, these aggregates are not strict, that is
|
|
they do not drop input rows containing nulls. Null values sort according
|
|
to the rule specified in the <literal>ORDER BY</literal> clause.
|
|
</para>
|
|
|
|
<table id="functions-grouping-table">
|
|
<title>Grouping Operations</title>
|
|
|
|
<tgroup cols="3">
|
|
<thead>
|
|
<row>
|
|
<entry>Function</entry>
|
|
<entry>Return Type</entry>
|
|
<entry>Description</entry>
|
|
</row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>GROUPING</primary>
|
|
</indexterm>
|
|
<function>GROUPING(<replaceable class="parameter">args...</replaceable>)</function>
|
|
</entry>
|
|
<entry>
|
|
<type>integer</type>
|
|
</entry>
|
|
<entry>
|
|
Integer bit mask indicating which arguments are not being included in the current
|
|
grouping set
|
|
</entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
Grouping operations are used in conjunction with grouping sets (see
|
|
<xref linkend="queries-grouping-sets"/>) to distinguish result rows. The
|
|
arguments to the <literal>GROUPING</literal> operation are not actually evaluated,
|
|
but they must match exactly expressions given in the <literal>GROUP BY</literal>
|
|
clause of the associated query level. Bits are assigned with the rightmost
|
|
argument being the least-significant bit; each bit is 0 if the corresponding
|
|
expression is included in the grouping criteria of the grouping set generating
|
|
the result row, and 1 if it is not. For example:
|
|
<screen>
|
|
<prompt>=></prompt> <userinput>SELECT * FROM items_sold;</userinput>
|
|
make | model | sales
|
|
-------+-------+-------
|
|
Foo | GT | 10
|
|
Foo | Tour | 20
|
|
Bar | City | 15
|
|
Bar | Sport | 5
|
|
(4 rows)
|
|
|
|
<prompt>=></prompt> <userinput>SELECT make, model, GROUPING(make,model), sum(sales) FROM items_sold GROUP BY ROLLUP(make,model);</userinput>
|
|
make | model | grouping | sum
|
|
-------+-------+----------+-----
|
|
Foo | GT | 0 | 10
|
|
Foo | Tour | 0 | 20
|
|
Bar | City | 0 | 15
|
|
Bar | Sport | 0 | 5
|
|
Foo | | 1 | 30
|
|
Bar | | 1 | 20
|
|
| | 3 | 50
|
|
(7 rows)
|
|
</screen>
|
|
</para>
|
|
|
|
</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, and <xref linkend="syntax-window-functions"/> for syntax
|
|
details.
|
|
</para>
|
|
|
|
<para>
|
|
The built-in window functions are listed in
|
|
<xref linkend="functions-window-table"/>. Note that these functions
|
|
<emphasis>must</emphasis> be invoked using window function syntax, i.e., an
|
|
<literal>OVER</literal> clause is required.
|
|
</para>
|
|
|
|
<para>
|
|
In addition to these functions, any built-in or user-defined
|
|
general-purpose or statistical
|
|
aggregate (i.e., not ordered-set or hypothetical-set aggregates)
|
|
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</literal>
|
|
clause follows the call; otherwise they act as non-window aggregates
|
|
and return a single row for the entire set.
|
|
</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</function> 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</function> - 1) / (total partition rows - 1)</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>cume_dist</primary>
|
|
</indexterm>
|
|
<function>cume_dist()</function>
|
|
</entry>
|
|
<entry>
|
|
<type>double precision</type>
|
|
</entry>
|
|
<entry>cumulative distribution: (number of partition rows preceding or peer with current row) / total partition rows</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>ntile</primary>
|
|
</indexterm>
|
|
<function>ntile(<replaceable class="parameter">num_buckets</replaceable> <type>integer</type>)</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>anyelement</type>
|
|
[, <replaceable class="parameter">offset</replaceable> <type>integer</type>
|
|
[, <replaceable class="parameter">default</replaceable> <type>anyelement</type> ]])
|
|
</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>
|
|
(which must be of the same type as
|
|
<replaceable class="parameter">value</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>anyelement</type>
|
|
[, <replaceable class="parameter">offset</replaceable> <type>integer</type>
|
|
[, <replaceable class="parameter">default</replaceable> <type>anyelement</type> ]])
|
|
</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>
|
|
(which must be of the same type as
|
|
<replaceable class="parameter">value</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</type>)</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</type>)</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</type>, <replaceable class="parameter">nth</replaceable> <type>integer</type>)
|
|
</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</literal> clause of the associated window
|
|
definition. Rows that are not distinct when considering only the
|
|
<literal>ORDER BY</literal> columns are said to be <firstterm>peers</firstterm>.
|
|
The four ranking functions (including <function>cume_dist</function>) are
|
|
defined so that they give the same answer for all peer rows.
|
|
</para>
|
|
|
|
<para>
|
|
Note that <function>first_value</function>, <function>last_value</function>, and
|
|
<function>nth_value</function> consider only the rows within the <quote>window
|
|
frame</quote>, 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</function> and
|
|
sometimes also <function>nth_value</function>. You can redefine the frame by
|
|
adding a suitable frame specification (<literal>RANGE</literal>,
|
|
<literal>ROWS</literal> or <literal>GROUPS</literal>) to
|
|
the <literal>OVER</literal> 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</literal> and the default window frame
|
|
definition produces a <quote>running sum</quote> type of behavior, which may or
|
|
may not be what's wanted. To obtain
|
|
aggregation over the whole partition, omit <literal>ORDER BY</literal> or use
|
|
<literal>ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING</literal>.
|
|
Other frame specifications can be used to obtain other effects.
|
|
</para>
|
|
|
|
<note>
|
|
<para>
|
|
The SQL standard defines a <literal>RESPECT NULLS</literal> or
|
|
<literal>IGNORE NULLS</literal> option for <function>lead</function>, <function>lag</function>,
|
|
<function>first_value</function>, <function>last_value</function>, and
|
|
<function>nth_value</function>. This is not implemented in
|
|
<productname>PostgreSQL</productname>: the behavior is always the
|
|
same as the standard's default, namely <literal>RESPECT NULLS</literal>.
|
|
Likewise, the standard's <literal>FROM FIRST</literal> or <literal>FROM LAST</literal>
|
|
option for <function>nth_value</function> is not implemented: only the
|
|
default <literal>FROM FIRST</literal> behavior is supported. (You can achieve
|
|
the result of <literal>FROM LAST</literal> by reversing the <literal>ORDER BY</literal>
|
|
ordering.)
|
|
</para>
|
|
</note>
|
|
|
|
<para>
|
|
<function>cume_dist</function> computes the fraction of partition rows that
|
|
are less than or equal to the current row and its peers, while
|
|
<function>percent_rank</function> computes the fraction of partition rows that
|
|
are less than the current row, assuming the current row does not exist
|
|
in the partition.
|
|
</para>
|
|
|
|
</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 id="functions-subquery-exists">
|
|
<title><literal>EXISTS</literal></title>
|
|
|
|
<synopsis>
|
|
EXISTS (<replaceable>subquery</replaceable>)
|
|
</synopsis>
|
|
|
|
<para>
|
|
The argument of <token>EXISTS</token> is an arbitrary <command>SELECT</command> 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</quote>; if the subquery returns no rows, the result of <token>EXISTS</token>
|
|
is <quote>false</quote>.
|
|
</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</literal> 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</literal>, but
|
|
it produces at most one output row for each <literal>tab1</literal> row,
|
|
even if there are several matching <literal>tab2</literal> rows:
|
|
<screen>
|
|
SELECT col1
|
|
FROM tab1
|
|
WHERE EXISTS (SELECT 1 FROM tab2 WHERE col2 = tab1.col2);
|
|
</screen>
|
|
</para>
|
|
</sect2>
|
|
|
|
<sect2 id="functions-subquery-in">
|
|
<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</quote> if any equal subquery row is found.
|
|
The result is <quote>false</quote> 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</quote> if any equal subquery row is found.
|
|
The result is <quote>false</quote> 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 id="functions-subquery-notin">
|
|
<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</quote> if only unequal subquery rows
|
|
are found (including the case where the subquery returns no rows).
|
|
The result is <quote>false</quote> 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</quote> if only unequal subquery rows
|
|
are found (including the case where the subquery returns no rows).
|
|
The result is <quote>false</quote> 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 id="functions-subquery-any-some">
|
|
<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</quote> if any true result is obtained.
|
|
The result is <quote>false</quote> 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</replaceable> ANY (<replaceable>subquery</replaceable>)
|
|
<replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> 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</quote> if the comparison
|
|
returns true for any subquery row.
|
|
The result is <quote>false</quote> if the comparison returns false for every
|
|
subquery row (including the case where the subquery returns no
|
|
rows).
|
|
The result is NULL if no comparison with a subquery row returns true,
|
|
and at least one comparison returns NULL.
|
|
</para>
|
|
|
|
<para>
|
|
See <xref linkend="row-wise-comparison"/> for details about the meaning
|
|
of a row constructor comparison.
|
|
</para>
|
|
</sect2>
|
|
|
|
<sect2 id="functions-subquery-all">
|
|
<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</quote> if all rows yield true
|
|
(including the case where the subquery returns no rows).
|
|
The result is <quote>false</quote> if any false result is found.
|
|
The result is NULL if no comparison with a subquery row returns false,
|
|
and at least one comparison returns NULL.
|
|
</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</quote> if the comparison
|
|
returns true for all subquery rows (including the
|
|
case where the subquery returns no rows).
|
|
The result is <quote>false</quote> if the comparison returns false for any
|
|
subquery row.
|
|
The result is NULL if no comparison with a subquery row returns false,
|
|
and at least one comparison returns NULL.
|
|
</para>
|
|
|
|
<para>
|
|
See <xref linkend="row-wise-comparison"/> for details about the meaning
|
|
of a row constructor comparison.
|
|
</para>
|
|
</sect2>
|
|
|
|
<sect2>
|
|
<title>Single-Row 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 constructor 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>composite type</primary>
|
|
<secondary>comparison</secondary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>row-wise comparison</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>comparison</primary>
|
|
<secondary>composite type</secondary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>comparison</primary>
|
|
<secondary>row constructor</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 id="functions-comparisons-in-scalar">
|
|
<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</quote> 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</quote> if any true result is obtained.
|
|
The result is <quote>false</quote> 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</quote> if all comparisons yield true
|
|
(including the case where the array has zero elements).
|
|
The result is <quote>false</quote> 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 Constructor 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 constructor
|
|
comparisons are allowed when the <replaceable>operator</replaceable> is
|
|
<literal>=</literal>,
|
|
<literal><></literal>,
|
|
<literal><</literal>,
|
|
<literal><=</literal>,
|
|
<literal>></literal> or
|
|
<literal>>=</literal>.
|
|
Every row element must be of a type which has a default B-tree operator
|
|
class or the attempted comparison may generate an error.
|
|
</para>
|
|
|
|
<note>
|
|
<para>
|
|
Errors related to the number or types of elements might not occur if
|
|
the comparison is resolved using earlier columns.
|
|
</para>
|
|
</note>
|
|
|
|
<para>
|
|
The <literal>=</literal> and <literal><></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><=</literal>, <literal>></literal> and
|
|
<literal>>=</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)</literal>
|
|
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><=</literal>, <literal>></literal> and <literal>>=</literal>
|
|
cases were not handled per SQL specification. A comparison like
|
|
<literal>ROW(a,b) < ROW(c,d)</literal>
|
|
was implemented as
|
|
<literal>a < c AND b < d</literal>
|
|
whereas the correct behavior is equivalent to
|
|
<literal>a < c OR (a = c AND b < d)</literal>.
|
|
</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>
|
|
|
|
</sect2>
|
|
|
|
<sect2 id="composite-type-comparison">
|
|
<title>Composite Type Comparison</title>
|
|
|
|
<synopsis>
|
|
<replaceable>record</replaceable> <replaceable>operator</replaceable> <replaceable>record</replaceable>
|
|
</synopsis>
|
|
|
|
<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 (as in
|
|
<xref linkend="row-wise-comparison"/>) 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>
|
|
|
|
<para>
|
|
Each side is evaluated and they are compared row-wise. Composite type
|
|
comparisons are allowed when the <replaceable>operator</replaceable> is
|
|
<literal>=</literal>,
|
|
<literal><></literal>,
|
|
<literal><</literal>,
|
|
<literal><=</literal>,
|
|
<literal>></literal> or
|
|
<literal>>=</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>=</literal> member of a B-tree operator
|
|
class.) The default behavior of the above operators is the same as for
|
|
<literal>IS [ NOT ] DISTINCT FROM</literal> for row constructors (see
|
|
<xref linkend="row-wise-comparison"/>).
|
|
</para>
|
|
|
|
<para>
|
|
To support matching of rows which include elements without a default
|
|
B-tree operator class, the following operators are defined for composite
|
|
type comparison:
|
|
<literal>*=</literal>,
|
|
<literal>*<></literal>,
|
|
<literal>*<</literal>,
|
|
<literal>*<=</literal>,
|
|
<literal>*></literal>, and
|
|
<literal>*>=</literal>.
|
|
These operators compare the internal binary representation of the two
|
|
rows. Two rows might have a different binary representation even
|
|
though comparisons of the two rows with the equality operator is true.
|
|
The ordering of rows under these comparison operators is deterministic
|
|
but not otherwise meaningful. These operators are used internally for
|
|
materialized views and might be useful for other specialized purposes
|
|
such as replication but are not intended to be generally useful for
|
|
writing queries.
|
|
</para>
|
|
</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.
|
|
The most widely used functions in this class are series generating
|
|
functions, as detailed in <xref linkend="functions-srf-series"/> and
|
|
<xref linkend="functions-srf-subscripts"/>. Other, more specialized
|
|
set-returning functions are described elsewhere in this manual.
|
|
See <xref linkend="queries-tablefunctions"/> for ways to combine multiple
|
|
set-returning functions.
|
|
</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>, <type>bigint</type> or <type>numeric</type></entry>
|
|
<entry><type>setof int</type>, <type>setof bigint</type>, or <type>setof numeric</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>, <type>bigint</type> or <type>numeric</type></entry>
|
|
<entry><type>setof int</type>, <type>setof bigint</type> or <type>setof numeric</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</type>)</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)
|
|
|
|
SELECT generate_series(1.1, 4, 1.3);
|
|
generate_series
|
|
-----------------
|
|
1.1
|
|
2.4
|
|
3.7
|
|
(3 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</function> 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
|
|
SELECT * FROM unnest2(ARRAY[[1,2],[3,4]]);
|
|
unnest2
|
|
---------
|
|
1
|
|
2
|
|
3
|
|
4
|
|
(4 rows)
|
|
</programlisting>
|
|
</para>
|
|
|
|
<indexterm>
|
|
<primary>ordinality</primary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
When a function in the <literal>FROM</literal> clause is suffixed
|
|
by <literal>WITH ORDINALITY</literal>, a <type>bigint</type> column is
|
|
appended to the output which starts from 1 and increments by 1 for each row
|
|
of the function's output. This is most useful in the case of set returning
|
|
functions such as <function>unnest()</function>.
|
|
|
|
<programlisting>
|
|
-- set returning function WITH ORDINALITY
|
|
SELECT * FROM pg_ls_dir('.') WITH ORDINALITY AS t(ls,n);
|
|
ls | n
|
|
-----------------+----
|
|
pg_serial | 1
|
|
pg_twophase | 2
|
|
postmaster.opts | 3
|
|
pg_notify | 4
|
|
postgresql.conf | 5
|
|
pg_tblspc | 6
|
|
logfile | 7
|
|
base | 8
|
|
postmaster.pid | 9
|
|
pg_ident.conf | 10
|
|
global | 11
|
|
pg_xact | 12
|
|
pg_snapshots | 13
|
|
pg_multixact | 14
|
|
PG_VERSION | 15
|
|
pg_wal | 16
|
|
pg_hba.conf | 17
|
|
pg_stat_tmp | 18
|
|
pg_subtrans | 19
|
|
(19 rows)
|
|
</programlisting>
|
|
</para>
|
|
|
|
</sect1>
|
|
|
|
<sect1 id="functions-info">
|
|
<title>System Information Functions and Operators</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_role</function></literal></entry>
|
|
<entry><type>name</type></entry>
|
|
<entry>equivalent to <function>current_user</function></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_blocking_pids(<type>int</type>)</function></literal></entry>
|
|
<entry><type>int[]</type></entry>
|
|
<entry>Process ID(s) that are blocking specified server process ID from acquiring a lock</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_current_logfile(<optional><type>text</type></optional>)</function></literal></entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>Primary log file name, or log in the requested format,
|
|
currently in use by the logging collector</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_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_jit_available()</function></literal></entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>is <acronym>JIT</acronym> compilation available in this session
|
|
(see <xref linkend="jit"/>)? Returns <literal>false</literal> if <xref
|
|
linkend="guc-jit"/> is set to false.</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_notification_queue_usage()</function></literal></entry>
|
|
<entry><type>double</type></entry>
|
|
<entry>fraction of the asynchronous notification queue currently occupied (0-1)</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>pg_safe_snapshot_blocking_pids(<type>int</type>)</function></literal></entry>
|
|
<entry><type>int[]</type></entry>
|
|
<entry>Process ID(s) that are blocking specified server process ID from acquiring a safe snapshot</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal><function>pg_trigger_depth()</function></literal></entry>
|
|
<entry><type>int</type></entry>
|
|
<entry>current nesting level of <productname>PostgreSQL</productname> triggers
|
|
(0 if not called, directly or indirectly, from inside a trigger)</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</productname> version information. See also <xref linkend="guc-server-version-num"/> for a machine-readable version.</entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<note>
|
|
<para>
|
|
<function>current_catalog</function>,
|
|
<function>current_role</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_role</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>.
|
|
<function>current_role</function> and <function>user</function> are
|
|
synonyms for <function>current_user</function>. (The SQL standard draws
|
|
a distinction between <function>current_role</function>
|
|
and <function>current_user</function>, but <productname>PostgreSQL</productname>
|
|
does not, since it unifies users and roles into a single kind of entity.)
|
|
</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</literal> 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</replaceable> <optional>, <replaceable>schema</replaceable>, ...</optional>
|
|
</programlisting>
|
|
</para>
|
|
</note>
|
|
|
|
<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_blocking_pids</primary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
<function>pg_blocking_pids</function> returns an array of the process IDs
|
|
of the sessions that are blocking the server process with the specified
|
|
process ID, or an empty array if there is no such server process or it is
|
|
not blocked. One server process blocks another if it either holds a lock
|
|
that conflicts with the blocked process's lock request (hard block), or is
|
|
waiting for a lock that would conflict with the blocked process's lock
|
|
request and is ahead of it in the wait queue (soft block). When using
|
|
parallel queries the result always lists client-visible process IDs (that
|
|
is, <function>pg_backend_pid</function> results) even if the actual lock is held
|
|
or awaited by a child worker process. As a result of that, there may be
|
|
duplicated PIDs in the result. Also note that when a prepared transaction
|
|
holds a conflicting lock, it will be represented by a zero process ID in
|
|
the result of this function.
|
|
Frequent calls to this function could have some impact on database
|
|
performance, because it needs exclusive access to the lock manager's
|
|
shared state for a short time.
|
|
</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>pg_current_logfile</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>Logging</primary>
|
|
<secondary>pg_current_logfile function</secondary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>current_logfiles</primary>
|
|
<secondary>and the pg_current_logfile function</secondary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>Logging</primary>
|
|
<secondary>current_logfiles file and the pg_current_logfile
|
|
function</secondary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
<function>pg_current_logfile</function> returns, as <type>text</type>,
|
|
the path of the log file(s) currently in use by the logging collector.
|
|
The path includes the <xref linkend="guc-log-directory"/> directory
|
|
and the log file name. Log collection must be enabled or the return value
|
|
is <literal>NULL</literal>. When multiple log files exist, each in a
|
|
different format, <function>pg_current_logfile</function> called
|
|
without arguments returns the path of the file having the first format
|
|
found in the ordered list: <systemitem>stderr</systemitem>, <systemitem>csvlog</systemitem>.
|
|
<literal>NULL</literal> is returned when no log file has any of these
|
|
formats. To request a specific file format supply, as <type>text</type>,
|
|
either <systemitem>csvlog</systemitem> or <systemitem>stderr</systemitem> as the value of the
|
|
optional parameter. The return value is <literal>NULL</literal> when the
|
|
log format requested is not a configured
|
|
<xref linkend="guc-log-destination"/>. The
|
|
<function>pg_current_logfile</function> reflects the contents of the
|
|
<filename>current_logfiles</filename> file.
|
|
</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_listening_channels</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>pg_notification_queue_usage</primary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
<function>pg_listening_channels</function> returns a set of names of
|
|
asynchronous notification channels that the current session is listening
|
|
to. <function>pg_notification_queue_usage</function> returns the
|
|
fraction of the total available space for notifications currently
|
|
occupied by notifications that are waiting to be processed, as a
|
|
<type>double</type> in the range 0-1.
|
|
See <xref linkend="sql-listen"/> and <xref linkend="sql-notify"/>
|
|
for more information.
|
|
</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_safe_snapshot_blocking_pids</primary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
<function>pg_safe_snapshot_blocking_pids</function> returns an array of
|
|
the process IDs of the sessions that are blocking the server process with
|
|
the specified process ID from acquiring a safe snapshot, or an empty array
|
|
if there is no such server process or it is not blocked. A session
|
|
running a <literal>SERIALIZABLE</literal> transaction blocks
|
|
a <literal>SERIALIZABLE READ ONLY DEFERRABLE</literal> transaction from
|
|
acquiring a snapshot until the latter determines that it is safe to avoid
|
|
taking any predicate locks. See <xref linkend="xact-serializable"/> for
|
|
more information about serializable and deferrable transactions. Frequent
|
|
calls to this function could have some impact on database performance,
|
|
because it needs access to the predicate lock manager's shared
|
|
state for a short time.
|
|
</para>
|
|
|
|
<indexterm>
|
|
<primary>version</primary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
<function>version</function> returns a string describing the
|
|
<productname>PostgreSQL</productname> server's version. You can also
|
|
get this information from <xref linkend="guc-server-version"/> or
|
|
for a machine-readable version, <xref linkend="guc-server-version-num"/>.
|
|
Software developers should use <literal>server_version_num</literal>
|
|
(available since 8.2) or <xref linkend="libpq-pqserverversion"/> instead
|
|
of parsing the text 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>has_type_privilege</function>(<parameter>user</parameter>,
|
|
<parameter>type</parameter>,
|
|
<parameter>privilege</parameter>)</literal>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>does user have privilege for type</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>has_type_privilege</function>(<parameter>type</parameter>,
|
|
<parameter>privilege</parameter>)</literal>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>does current user have privilege for type</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>
|
|
<row>
|
|
<entry><literal><function>row_security_active</function>(<parameter>table</parameter>)</literal>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>does current user have row level security active for table</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>has_type_privilege</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>pg_has_role</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>row_security_active</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</literal> 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>,
|
|
<literal>REFERENCES</literal>, or <literal>TRIGGER</literal>. Optionally,
|
|
<literal>WITH GRANT OPTION</literal> 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</literal> 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</function>,
|
|
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</literal> if <function>has_table_privilege</function> does for the same
|
|
arguments. But <function>has_any_column_privilege</function> 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</type> 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>has_type_privilege</function> checks whether a user
|
|
can access a type in a particular way.
|
|
Its argument possibilities
|
|
are analogous to <function>has_table_privilege</function>.
|
|
When specifying a type by a text string rather than by OID,
|
|
the allowed input is the same as for the <type>regtype</type> data type
|
|
(see <xref linkend="datatype-oid"/>).
|
|
The desired access privilege type must evaluate to
|
|
<literal>USAGE</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</literal> 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</command>), while
|
|
<literal>USAGE</literal> denotes whether the privileges of the role
|
|
are immediately available without doing <command>SET ROLE</command>.
|
|
</para>
|
|
|
|
<para>
|
|
<function>row_security_active</function> checks whether row level
|
|
security is active for the specified table in the context of the
|
|
<function>current_user</function> and environment. The table can
|
|
be specified by name or by OID.
|
|
</para>
|
|
|
|
<para>
|
|
<xref linkend="functions-aclitem-fn-table"/> shows the operators
|
|
available for the <type>aclitem</type> type, which is the catalog
|
|
representation of access privileges. See <xref linkend="ddl-priv"/>
|
|
for information about how to read access privilege values.
|
|
</para>
|
|
|
|
<indexterm>
|
|
<primary>acldefault</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>aclitemeq</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>aclcontains</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>aclexplode</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>makeaclitem</primary>
|
|
</indexterm>
|
|
|
|
<table id="functions-aclitem-op-table">
|
|
<title><type>aclitem</type> 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>'calvin=r*w/hobbes'::aclitem = 'calvin=r*w*/hobbes'::aclitem</literal></entry>
|
|
<entry><literal>f</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>@></literal> </entry>
|
|
<entry>contains element</entry>
|
|
<entry><literal>'{calvin=r*w/hobbes,hobbes=r*w*/postgres}'::aclitem[] @> 'calvin=r*w/hobbes'::aclitem</literal></entry>
|
|
<entry><literal>t</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>~</literal> </entry>
|
|
<entry>contains element</entry>
|
|
<entry><literal>'{calvin=r*w/hobbes,hobbes=r*w*/postgres}'::aclitem[] ~ 'calvin=r*w/hobbes'::aclitem</literal></entry>
|
|
<entry><literal>t</literal></entry>
|
|
</row>
|
|
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
<xref linkend="functions-aclitem-fn-table"/> shows some additional
|
|
functions to manage the <type>aclitem</type> type.
|
|
</para>
|
|
|
|
<table id="functions-aclitem-fn-table">
|
|
<title><type>aclitem</type> Functions</title>
|
|
<tgroup cols="3">
|
|
<thead>
|
|
<row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
|
|
</thead>
|
|
<tbody>
|
|
<row>
|
|
<entry><literal><function>acldefault</function>(<parameter>type</parameter>,
|
|
<parameter>ownerId</parameter>)</literal></entry>
|
|
<entry><type>aclitem[]</type></entry>
|
|
<entry>get the default access privileges for an object belonging to <parameter>ownerId</parameter></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>aclexplode</function>(<parameter>aclitem[]</parameter>)</literal></entry>
|
|
<entry><type>setof record</type></entry>
|
|
<entry>get <type>aclitem</type> array as tuples</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>makeaclitem</function>(<parameter>grantee</parameter>, <parameter>grantor</parameter>, <parameter>privilege</parameter>, <parameter>grantable</parameter>)</literal></entry>
|
|
<entry><type>aclitem</type></entry>
|
|
<entry>build an <type>aclitem</type> from input</entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
<function>acldefault</function> returns the built-in default access
|
|
privileges for an object of type <parameter>type</parameter> belonging to
|
|
role <parameter>ownerId</parameter>. These represent the access
|
|
privileges that will be assumed when an object's ACL entry is null.
|
|
(The default access privileges are described in <xref linkend="ddl-priv"/>.)
|
|
The <parameter>type</parameter> parameter is a <type>CHAR</type>: write
|
|
'c' for <literal>COLUMN</literal>,
|
|
'r' for <literal>TABLE</literal> and table-like objects,
|
|
's' for <literal>SEQUENCE</literal>,
|
|
'd' for <literal>DATABASE</literal>,
|
|
'f' for <literal>FUNCTION</literal> or <literal>PROCEDURE</literal>,
|
|
'l' for <literal>LANGUAGE</literal>,
|
|
'L' for <literal>LARGE OBJECT</literal>,
|
|
'n' for <literal>SCHEMA</literal>,
|
|
't' for <literal>TABLESPACE</literal>,
|
|
'F' for <literal>FOREIGN DATA WRAPPER</literal>,
|
|
'S' for <literal>FOREIGN SERVER</literal>,
|
|
or
|
|
'T' for <literal>TYPE</literal> or <literal>DOMAIN</literal>.
|
|
</para>
|
|
|
|
<para>
|
|
<function>aclexplode</function> returns an <type>aclitem</type> array
|
|
as a set of rows. Output columns are grantor <type>oid</type>,
|
|
grantee <type>oid</type> (<literal>0</literal> for <literal>PUBLIC</literal>),
|
|
granted privilege as <type>text</type> (<literal>SELECT</literal>, ...)
|
|
and whether the privilege is grantable as <type>boolean</type>.
|
|
<function>makeaclitem</function> performs the inverse operation.
|
|
</para>
|
|
|
|
<para>
|
|
<xref linkend="functions-info-schema-table"/> shows functions that
|
|
determine whether a certain object is <firstterm>visible</firstterm> 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>
|
|
|
|
<indexterm>
|
|
<primary>search path</primary>
|
|
<secondary>object visibility</secondary>
|
|
</indexterm>
|
|
|
|
<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_opfamily_is_visible(<parameter>opclass_oid</parameter>)</function></literal>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>is operator family visible in search path</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>pg_statistics_obj_is_visible(<parameter>stat_oid</parameter>)</function></literal>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>is statistics object 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_opfamily_is_visible</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>pg_statistics_obj_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, materialized views, indexes, sequences and foreign tables;
|
|
<function>pg_function_is_visible</function> can also be used with
|
|
procedures and aggregates;
|
|
<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)</emphasis> 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>, <type>regtype</type>,
|
|
<type>regprocedure</type>, <type>regoperator</type>, <type>regconfig</type>,
|
|
or <type>regdictionary</type>),
|
|
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_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_statisticsobjdef</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_index_column_has_property</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>pg_index_has_property</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>pg_indexam_has_property</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>pg_options_to_table</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>pg_tablespace_databases</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>pg_tablespace_location</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>pg_typeof</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>collation for</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>to_regclass</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>to_regproc</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>to_regprocedure</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>to_regoper</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>to_regoperator</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>to_regtype</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>to_regnamespace</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>to_regrole</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</parameter>)</function></literal></entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>get SQL name of a data type</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</parameter>)</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</parameter>)</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>, <parameter>pretty_bool</parameter>)</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 or procedure</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 or procedure'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 or procedure (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</literal> clause for function (returns null for a procedure)</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> command for index</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>pg_get_indexdef(<parameter>index_oid</parameter>, <parameter>column_no</parameter>, <parameter>pretty_bool</parameter>)</function></literal></entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>get <command>CREATE INDEX</command> command for index,
|
|
or definition of just one index column when
|
|
<parameter>column_no</parameter> 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> command for rule</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>pg_get_ruledef(<parameter>rule_oid</parameter>, <parameter>pretty_bool</parameter>)</function></literal></entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>get <command>CREATE RULE</command> 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 serial or identity column uses</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>pg_get_statisticsobjdef(<parameter>statobj_oid</parameter>)</function></literal></entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>get <command>CREATE STATISTICS</command> command for extended statistics object</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> command for trigger</entry>
|
|
</row>
|
|
<row>
|
|
<entry><function>pg_get_triggerdef</function>(<parameter>trigger_oid</parameter>, <parameter>pretty_bool</parameter>)</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>get <command>CREATE [ CONSTRAINT ] TRIGGER</command> 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 or materialized view (<emphasis>deprecated</emphasis>)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>pg_get_viewdef(<parameter>view_name</parameter>, <parameter>pretty_bool</parameter>)</function></literal></entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>get underlying <command>SELECT</command> command for view or materialized 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 or materialized view</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>pg_get_viewdef(<parameter>view_oid</parameter>, <parameter>pretty_bool</parameter>)</function></literal></entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>get underlying <command>SELECT</command> command for view or materialized view</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>pg_get_viewdef(<parameter>view_oid</parameter>, <parameter>wrap_column_int</parameter>)</function></literal></entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>get underlying <command>SELECT</command> command for view or
|
|
materialized view; lines with fields are wrapped to specified
|
|
number of columns, pretty-printing is implied</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>pg_index_column_has_property(<parameter>index_oid</parameter>, <parameter>column_no</parameter>, <parameter>prop_name</parameter>)</function></literal></entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>test whether an index column has a specified property</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>pg_index_has_property(<parameter>index_oid</parameter>, <parameter>prop_name</parameter>)</function></literal></entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>test whether an index has a specified property</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>pg_indexam_has_property(<parameter>am_oid</parameter>, <parameter>prop_name</parameter>)</function></literal></entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>test whether an index access method has a specified property</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_tablespace_location(<parameter>tablespace_oid</parameter>)</function></literal></entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>get the path in the file system that this tablespace is located in</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>
|
|
<row>
|
|
<entry><literal><function>collation for (<parameter>any</parameter>)</function></literal></entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>get the collation of the argument</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>to_regclass(<parameter>rel_name</parameter>)</function></literal></entry>
|
|
<entry><type>regclass</type></entry>
|
|
<entry>get the OID of the named relation</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>to_regproc(<parameter>func_name</parameter>)</function></literal></entry>
|
|
<entry><type>regproc</type></entry>
|
|
<entry>get the OID of the named function</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>to_regprocedure(<parameter>func_name</parameter>)</function></literal></entry>
|
|
<entry><type>regprocedure</type></entry>
|
|
<entry>get the OID of the named function</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>to_regoper(<parameter>operator_name</parameter>)</function></literal></entry>
|
|
<entry><type>regoper</type></entry>
|
|
<entry>get the OID of the named operator</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>to_regoperator(<parameter>operator_name</parameter>)</function></literal></entry>
|
|
<entry><type>regoperator</type></entry>
|
|
<entry>get the OID of the named operator</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>to_regtype(<parameter>type_name</parameter>)</function></literal></entry>
|
|
<entry><type>regtype</type></entry>
|
|
<entry>get the OID of the named type</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>to_regnamespace(<parameter>schema_name</parameter>)</function></literal></entry>
|
|
<entry><type>regnamespace</type></entry>
|
|
<entry>get the OID of the named schema</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>to_regrole(<parameter>role_name</parameter>)</function></literal></entry>
|
|
<entry><type>regrole</type></entry>
|
|
<entry>get the OID of the named role</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</structfield> column
|
|
contains the keyword. The <structfield>catcode</structfield> column contains a
|
|
category code: <literal>U</literal> for unreserved, <literal>C</literal> for column name,
|
|
<literal>T</literal> for type or function name, or <literal>R</literal> for reserved.
|
|
The <structfield>catdesc</structfield> 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>,
|
|
<function>pg_get_statisticsobjdef</function>, and
|
|
<function>pg_get_triggerdef</function>, respectively reconstruct the
|
|
creating command for a constraint, index, rule, extended statistics object,
|
|
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</command> query that defines a view. Most of these functions come
|
|
in two variants, one of which can optionally <quote>pretty-print</quote> 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</productname>; avoid using pretty-printed output for dump
|
|
purposes. Passing <literal>false</literal> 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</function> returns a complete
|
|
<command>CREATE OR REPLACE FUNCTION</command> 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</command>.
|
|
<function>pg_get_function_result</function> similarly returns the
|
|
appropriate <literal>RETURNS</literal> 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</command>, 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. If the column is an identity column, the associated
|
|
sequence is the sequence internally created for the identity column. For
|
|
columns created using one of the serial types
|
|
(<type>serial</type>, <type>smallserial</type>, <type>bigserial</type>), it
|
|
is the sequence created for that serial column definition. In the latter
|
|
case, this association can be modified or removed with <command>ALTER
|
|
SEQUENCE OWNED BY</command>. (The function probably should have been called
|
|
<function>pg_get_owned_sequence</function>; its current name reflects the
|
|
fact that it has typically been used with <type>serial</type>
|
|
or <type>bigserial</type> columns.) 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"/>). A typical use is in reading the
|
|
current value of a sequence for an identity or serial column, for example:
|
|
<programlisting>
|
|
SELECT currval(pg_get_serial_sequence('sometable', 'id'));
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
<function>pg_get_userbyid</function> extracts a role's name given
|
|
its OID.
|
|
</para>
|
|
|
|
<para>
|
|
<function>pg_index_column_has_property</function>,
|
|
<function>pg_index_has_property</function>, and
|
|
<function>pg_indexam_has_property</function> return whether the
|
|
specified index column, index, or index access method possesses the named
|
|
property. <literal>NULL</literal> is returned if the property name is not
|
|
known or does not apply to the particular object, or if the OID or column
|
|
number does not identify a valid object. Refer to
|
|
<xref linkend="functions-info-index-column-props"/> for column properties,
|
|
<xref linkend="functions-info-index-props"/> for index properties, and
|
|
<xref linkend="functions-info-indexam-props"/> for access method properties.
|
|
(Note that extension access methods can define additional property names
|
|
for their indexes.)
|
|
</para>
|
|
|
|
<table id="functions-info-index-column-props">
|
|
<title>Index Column Properties</title>
|
|
<tgroup cols="2">
|
|
<thead>
|
|
<row><entry>Name</entry><entry>Description</entry></row>
|
|
</thead>
|
|
<tbody>
|
|
<row>
|
|
<entry><literal>asc</literal></entry>
|
|
<entry>Does the column sort in ascending order on a forward scan?
|
|
</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>desc</literal></entry>
|
|
<entry>Does the column sort in descending order on a forward scan?
|
|
</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>nulls_first</literal></entry>
|
|
<entry>Does the column sort with nulls first on a forward scan?
|
|
</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>nulls_last</literal></entry>
|
|
<entry>Does the column sort with nulls last on a forward scan?
|
|
</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>orderable</literal></entry>
|
|
<entry>Does the column possess any defined sort ordering?
|
|
</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>distance_orderable</literal></entry>
|
|
<entry>Can the column be scanned in order by a <quote>distance</quote>
|
|
operator, for example <literal>ORDER BY col <-> constant</literal> ?
|
|
</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>returnable</literal></entry>
|
|
<entry>Can the column value be returned by an index-only scan?
|
|
</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>search_array</literal></entry>
|
|
<entry>Does the column natively support <literal>col = ANY(array)</literal>
|
|
searches?
|
|
</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>search_nulls</literal></entry>
|
|
<entry>Does the column support <literal>IS NULL</literal> and
|
|
<literal>IS NOT NULL</literal> searches?
|
|
</entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<table id="functions-info-index-props">
|
|
<title>Index Properties</title>
|
|
<tgroup cols="2">
|
|
<thead>
|
|
<row><entry>Name</entry><entry>Description</entry></row>
|
|
</thead>
|
|
<tbody>
|
|
<row>
|
|
<entry><literal>clusterable</literal></entry>
|
|
<entry>Can the index be used in a <literal>CLUSTER</literal> command?
|
|
</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>index_scan</literal></entry>
|
|
<entry>Does the index support plain (non-bitmap) scans?
|
|
</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>bitmap_scan</literal></entry>
|
|
<entry>Does the index support bitmap scans?
|
|
</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>backward_scan</literal></entry>
|
|
<entry>Can the scan direction be changed in mid-scan (to
|
|
support <literal>FETCH BACKWARD</literal> on a cursor without
|
|
needing materialization)?
|
|
</entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<table id="functions-info-indexam-props">
|
|
<title>Index Access Method Properties</title>
|
|
<tgroup cols="2">
|
|
<thead>
|
|
<row><entry>Name</entry><entry>Description</entry></row>
|
|
</thead>
|
|
<tbody>
|
|
<row>
|
|
<entry><literal>can_order</literal></entry>
|
|
<entry>Does the access method support <literal>ASC</literal>,
|
|
<literal>DESC</literal> and related keywords in
|
|
<literal>CREATE INDEX</literal>?
|
|
</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>can_unique</literal></entry>
|
|
<entry>Does the access method support unique indexes?
|
|
</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>can_multi_col</literal></entry>
|
|
<entry>Does the access method support indexes with multiple columns?
|
|
</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>can_exclude</literal></entry>
|
|
<entry>Does the access method support exclusion constraints?
|
|
</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>can_include</literal></entry>
|
|
<entry>Does the access method support the <literal>INCLUDE</literal>
|
|
clause of <literal>CREATE INDEX</literal>?
|
|
</entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
<function>pg_options_to_table</function> returns the set of storage
|
|
option name/value pairs
|
|
(<replaceable>option_name</replaceable>/<replaceable>option_value</replaceable>) when passed
|
|
<structname>pg_class</structname>.<structfield>reloptions</structfield> or
|
|
<structname>pg_attribute</structname>.<structfield>attoptions</structfield>.
|
|
</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</structname> catalogs.
|
|
</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</type>, 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>
|
|
|
|
<para>
|
|
The expression <literal>collation for</literal> returns the collation of the
|
|
value that is passed to it. Example:
|
|
<programlisting>
|
|
SELECT collation for (description) FROM pg_description LIMIT 1;
|
|
pg_collation_for
|
|
------------------
|
|
"default"
|
|
(1 row)
|
|
|
|
SELECT collation for ('foo' COLLATE "de_DE");
|
|
pg_collation_for
|
|
------------------
|
|
"de_DE"
|
|
(1 row)
|
|
</programlisting>
|
|
The value might be quoted and schema-qualified. If no collation is derived
|
|
for the argument expression, then a null value is returned. If the argument
|
|
is not of a collatable data type, then an error is raised.
|
|
</para>
|
|
|
|
<para>
|
|
The <function>to_regclass</function>, <function>to_regproc</function>,
|
|
<function>to_regprocedure</function>, <function>to_regoper</function>,
|
|
<function>to_regoperator</function>, <function>to_regtype</function>,
|
|
<function>to_regnamespace</function>, and <function>to_regrole</function>
|
|
functions translate relation, function, operator, type, schema, and role
|
|
names (given as <type>text</type>) to objects of
|
|
type <type>regclass</type>, <type>regproc</type>, <type>regprocedure</type>,
|
|
<type>regoper</type>, <type>regoperator</type>, <type>regtype</type>,
|
|
<type>regnamespace</type>, and <type>regrole</type>
|
|
respectively. These functions differ from a cast from
|
|
text in that they don't accept a numeric OID, and that they return null
|
|
rather than throwing an error if the name is not found (or, for
|
|
<function>to_regproc</function> and <function>to_regoper</function>, if
|
|
the given name matches multiple objects).
|
|
</para>
|
|
|
|
<indexterm>
|
|
<primary>pg_describe_object</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>pg_identify_object</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>pg_identify_object_as_address</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>pg_get_object_address</primary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
<xref linkend="functions-info-object-table"/> lists functions related to
|
|
database object identification and addressing.
|
|
</para>
|
|
|
|
<table id="functions-info-object-table">
|
|
<title>Object Information and Addressing 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_describe_object(<parameter>classid</parameter> <type>oid</type>, <parameter>objid</parameter> <type>oid</type>, <parameter>objsubid</parameter> <type>integer</type>)</function></literal></entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>get description of a database object</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>pg_identify_object(<parameter>classid</parameter> <type>oid</type>, <parameter>objid</parameter> <type>oid</type>, <parameter>objsubid</parameter> <type>integer</type>)</function></literal></entry>
|
|
<entry><parameter>type</parameter> <type>text</type>, <parameter>schema</parameter> <type>text</type>, <parameter>name</parameter> <type>text</type>, <parameter>identity</parameter> <type>text</type></entry>
|
|
<entry>get identity of a database object</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>pg_identify_object_as_address(<parameter>classid</parameter> <type>oid</type>, <parameter>objid</parameter> <type>oid</type>, <parameter>objsubid</parameter> <type>integer</type>)</function></literal></entry>
|
|
<entry><parameter>type</parameter> <type>text</type>, <parameter>object_names</parameter> <type>text[]</type>, <parameter>object_args</parameter> <type>text[]</type></entry>
|
|
<entry>get external representation of a database object's address</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>pg_get_object_address(<parameter>type</parameter> <type>text</type>, <parameter>object_names</parameter> <type>text[]</type>, <parameter>object_args</parameter> <type>text[]</type>)</function></literal></entry>
|
|
<entry><parameter>classid</parameter> <type>oid</type>, <parameter>objid</parameter> <type>oid</type>, <parameter>objsubid</parameter> <type>integer</type></entry>
|
|
<entry>get address of a database object from its external representation</entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
<function>pg_describe_object</function> returns a textual description of a database
|
|
object specified by catalog OID, object OID, and sub-object ID (such as
|
|
a column number within a table; the sub-object ID is zero when referring
|
|
to a whole object).
|
|
This description is intended to be human-readable, and might be translated,
|
|
depending on server configuration.
|
|
This is useful to determine the identity of an object as stored in the
|
|
<structname>pg_depend</structname> catalog.
|
|
</para>
|
|
|
|
<para>
|
|
<function>pg_identify_object</function> returns a row containing enough information
|
|
to uniquely identify the database object specified by catalog OID, object OID and
|
|
sub-object ID. This information is intended to be machine-readable,
|
|
and is never translated.
|
|
<parameter>type</parameter> identifies the type of database object;
|
|
<parameter>schema</parameter> is the schema name that the object belongs in, or
|
|
<literal>NULL</literal> for object types that do not belong to schemas;
|
|
<parameter>name</parameter> is the name of the object, quoted if necessary,
|
|
if the name (along with schema name, if pertinent) is sufficient to
|
|
uniquely identify the object, otherwise <literal>NULL</literal>;
|
|
<parameter>identity</parameter> is the complete object identity, with the
|
|
precise format depending on object type, and each name within the format
|
|
being schema-qualified and quoted as necessary.
|
|
</para>
|
|
|
|
<para>
|
|
<function>pg_identify_object_as_address</function> returns a row containing
|
|
enough information to uniquely identify the database object specified by
|
|
catalog OID, object OID and sub-object ID. The returned
|
|
information is independent of the current server, that is, it could be used
|
|
to identify an identically named object in another server.
|
|
<parameter>type</parameter> identifies the type of database object;
|
|
<parameter>object_names</parameter> and <parameter>object_args</parameter>
|
|
are text arrays that together form a reference to the object.
|
|
These three values can be passed to
|
|
<function>pg_get_object_address</function> to obtain the internal address
|
|
of the object.
|
|
This function is the inverse of <function>pg_get_object_address</function>.
|
|
</para>
|
|
|
|
<para>
|
|
<function>pg_get_object_address</function> returns a row containing enough
|
|
information to uniquely identify the database object specified by its
|
|
type and object name and argument arrays. The returned values are the
|
|
ones that would be used in system catalogs such as <structname>pg_depend</structname>
|
|
and can be passed to other system functions such as
|
|
<function>pg_identify_object</function> or <function>pg_describe_object</function>.
|
|
<parameter>classid</parameter> is the OID of the system catalog containing the
|
|
object;
|
|
<parameter>objid</parameter> is the OID of the object itself, and
|
|
<parameter>objsubid</parameter> is the sub-object ID, or zero if none.
|
|
This function is the inverse of <function>pg_identify_object_as_address</function>.
|
|
</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_if_assigned</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>
|
|
|
|
<indexterm>
|
|
<primary>txid_status</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, assigning a new one if the current transaction does not have one</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>txid_current_if_assigned()</function></literal></entry>
|
|
<entry><type>bigint</type></entry>
|
|
<entry>same as <function>txid_current()</function> but returns null instead of assigning a new transaction ID if none is already assigned</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 <literal>xmax</literal> 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 <literal>xmin</literal> 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>
|
|
<row>
|
|
<entry><literal><function>txid_status(<parameter>bigint</parameter>)</function></literal></entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>report the status of the given transaction: <literal>committed</literal>, <literal>aborted</literal>, <literal>in progress</literal>, or null if the transaction ID is too old</entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
The internal transaction ID type (<type>xid</type>) 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</quote> 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</literal>
|
|
and <literal>xmax</literal>; there might be active txids higher
|
|
than <literal>xmax</literal>. 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</type>'s textual representation is
|
|
<literal><replaceable>xmin</replaceable>:<replaceable>xmax</replaceable>:<replaceable>xip_list</replaceable></literal>.
|
|
For example <literal>10:20:10,14,15</literal> means
|
|
<literal>xmin=10, xmax=20, xip_list=10, 14, 15</literal>.
|
|
</para>
|
|
|
|
<para>
|
|
<function>txid_status(bigint)</function> reports the commit status of a recent
|
|
transaction. Applications may use it to determine whether a transaction
|
|
committed or aborted when the application and database server become
|
|
disconnected while a <literal>COMMIT</literal> is in progress.
|
|
The status of a transaction will be reported as either
|
|
<literal>in progress</literal>,
|
|
<literal>committed</literal>, or <literal>aborted</literal>, provided that the
|
|
transaction is recent enough that the system retains the commit status
|
|
of that transaction. If is old enough that no references to that
|
|
transaction survive in the system and the commit status information has
|
|
been discarded, this function will return NULL. Note that prepared
|
|
transactions are reported as <literal>in progress</literal>; applications must
|
|
check <link
|
|
linkend="view-pg-prepared-xacts"><literal>pg_prepared_xacts</literal></link> if they
|
|
need to determine whether the txid is a prepared transaction.
|
|
</para>
|
|
|
|
<para>
|
|
The functions shown in <xref linkend="functions-commit-timestamp"/>
|
|
provide information about transactions that have been already committed.
|
|
These functions mainly provide information about when the transactions
|
|
were committed. They only provide useful data when
|
|
<xref linkend="guc-track-commit-timestamp"/> configuration option is enabled
|
|
and only for transactions that were committed after it was enabled.
|
|
</para>
|
|
|
|
<table id="functions-commit-timestamp">
|
|
<title>Committed Transaction Information</title>
|
|
<tgroup cols="3">
|
|
<thead>
|
|
<row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
<row>
|
|
<entry>
|
|
<indexterm><primary>pg_xact_commit_timestamp</primary></indexterm>
|
|
<literal><function>pg_xact_commit_timestamp(<parameter>xid</parameter>)</function></literal>
|
|
</entry>
|
|
<entry><type>timestamp with time zone</type></entry>
|
|
<entry>get commit timestamp of a transaction</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm><primary>pg_last_committed_xact</primary></indexterm>
|
|
<literal><function>pg_last_committed_xact()</function></literal>
|
|
</entry>
|
|
<entry><parameter>xid</parameter> <type>xid</type>, <parameter>timestamp</parameter> <type>timestamp with time zone</type></entry>
|
|
<entry>get transaction ID and commit timestamp of latest committed transaction</entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
The functions shown in <xref linkend="functions-controldata"/>
|
|
print information initialized during <command>initdb</command>, such
|
|
as the catalog version. They also show information about write-ahead
|
|
logging and checkpoint processing. This information is cluster-wide,
|
|
and not specific to any one database. They provide most of the same
|
|
information, from the same source, as
|
|
<xref linkend="app-pgcontroldata"/>, although in a form better suited
|
|
to <acronym>SQL</acronym> functions.
|
|
</para>
|
|
|
|
<table id="functions-controldata">
|
|
<title>Control Data Functions</title>
|
|
<tgroup cols="3">
|
|
<thead>
|
|
<row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
<row>
|
|
<entry>
|
|
<indexterm><primary>pg_control_checkpoint</primary></indexterm>
|
|
<literal><function>pg_control_checkpoint()</function></literal>
|
|
</entry>
|
|
<entry><type>record</type></entry>
|
|
<entry>
|
|
Returns information about current checkpoint state.
|
|
</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm><primary>pg_control_system</primary></indexterm>
|
|
<literal><function>pg_control_system()</function></literal>
|
|
</entry>
|
|
<entry><type>record</type></entry>
|
|
<entry>
|
|
Returns information about current control file state.
|
|
</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm><primary>pg_control_init</primary></indexterm>
|
|
<literal><function>pg_control_init()</function></literal>
|
|
</entry>
|
|
<entry><type>record</type></entry>
|
|
<entry>
|
|
Returns information about cluster initialization state.
|
|
</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm><primary>pg_control_recovery</primary></indexterm>
|
|
<literal><function>pg_control_recovery()</function></literal>
|
|
</entry>
|
|
<entry><type>record</type></entry>
|
|
<entry>
|
|
Returns information about recovery state.
|
|
</entry>
|
|
</row>
|
|
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
<function>pg_control_checkpoint</function> returns a record, shown in
|
|
<xref linkend="functions-pg-control-checkpoint"/>
|
|
</para>
|
|
|
|
<table id="functions-pg-control-checkpoint">
|
|
<title><function>pg_control_checkpoint</function> Columns</title>
|
|
<tgroup cols="2">
|
|
<thead>
|
|
<row>
|
|
<entry>Column Name</entry>
|
|
<entry>Data Type</entry>
|
|
</row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
|
|
<row>
|
|
<entry><literal>checkpoint_lsn</literal></entry>
|
|
<entry><type>pg_lsn</type></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>redo_lsn</literal></entry>
|
|
<entry><type>pg_lsn</type></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>redo_wal_file</literal></entry>
|
|
<entry><type>text</type></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>timeline_id</literal></entry>
|
|
<entry><type>integer</type></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>prev_timeline_id</literal></entry>
|
|
<entry><type>integer</type></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>full_page_writes</literal></entry>
|
|
<entry><type>boolean</type></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>next_xid</literal></entry>
|
|
<entry><type>text</type></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>next_oid</literal></entry>
|
|
<entry><type>oid</type></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>next_multixact_id</literal></entry>
|
|
<entry><type>xid</type></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>next_multi_offset</literal></entry>
|
|
<entry><type>xid</type></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>oldest_xid</literal></entry>
|
|
<entry><type>xid</type></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>oldest_xid_dbid</literal></entry>
|
|
<entry><type>oid</type></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>oldest_active_xid</literal></entry>
|
|
<entry><type>xid</type></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>oldest_multi_xid</literal></entry>
|
|
<entry><type>xid</type></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>oldest_multi_dbid</literal></entry>
|
|
<entry><type>oid</type></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>oldest_commit_ts_xid</literal></entry>
|
|
<entry><type>xid</type></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>newest_commit_ts_xid</literal></entry>
|
|
<entry><type>xid</type></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>checkpoint_time</literal></entry>
|
|
<entry><type>timestamp with time zone</type></entry>
|
|
</row>
|
|
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
<function>pg_control_system</function> returns a record, shown in
|
|
<xref linkend="functions-pg-control-system"/>
|
|
</para>
|
|
|
|
<table id="functions-pg-control-system">
|
|
<title><function>pg_control_system</function> Columns</title>
|
|
<tgroup cols="2">
|
|
<thead>
|
|
<row>
|
|
<entry>Column Name</entry>
|
|
<entry>Data Type</entry>
|
|
</row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
|
|
<row>
|
|
<entry><literal>pg_control_version</literal></entry>
|
|
<entry><type>integer</type></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>catalog_version_no</literal></entry>
|
|
<entry><type>integer</type></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>system_identifier</literal></entry>
|
|
<entry><type>bigint</type></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>pg_control_last_modified</literal></entry>
|
|
<entry><type>timestamp with time zone</type></entry>
|
|
</row>
|
|
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
<function>pg_control_init</function> returns a record, shown in
|
|
<xref linkend="functions-pg-control-init"/>
|
|
</para>
|
|
|
|
<table id="functions-pg-control-init">
|
|
<title><function>pg_control_init</function> Columns</title>
|
|
<tgroup cols="2">
|
|
<thead>
|
|
<row>
|
|
<entry>Column Name</entry>
|
|
<entry>Data Type</entry>
|
|
</row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
|
|
<row>
|
|
<entry><literal>max_data_alignment</literal></entry>
|
|
<entry><type>integer</type></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>database_block_size</literal></entry>
|
|
<entry><type>integer</type></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>blocks_per_segment</literal></entry>
|
|
<entry><type>integer</type></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>wal_block_size</literal></entry>
|
|
<entry><type>integer</type></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>bytes_per_wal_segment</literal></entry>
|
|
<entry><type>integer</type></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>max_identifier_length</literal></entry>
|
|
<entry><type>integer</type></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>max_index_columns</literal></entry>
|
|
<entry><type>integer</type></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>max_toast_chunk_size</literal></entry>
|
|
<entry><type>integer</type></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>large_object_chunk_size</literal></entry>
|
|
<entry><type>integer</type></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>float4_pass_by_value</literal></entry>
|
|
<entry><type>boolean</type></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>float8_pass_by_value</literal></entry>
|
|
<entry><type>boolean</type></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>data_page_checksum_version</literal></entry>
|
|
<entry><type>integer</type></entry>
|
|
</row>
|
|
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
<function>pg_control_recovery</function> returns a record, shown in
|
|
<xref linkend="functions-pg-control-recovery"/>
|
|
</para>
|
|
|
|
<table id="functions-pg-control-recovery">
|
|
<title><function>pg_control_recovery</function> Columns</title>
|
|
<tgroup cols="2">
|
|
<thead>
|
|
<row>
|
|
<entry>Column Name</entry>
|
|
<entry>Data Type</entry>
|
|
</row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
|
|
<row>
|
|
<entry><literal>min_recovery_end_lsn</literal></entry>
|
|
<entry><type>pg_lsn</type></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>min_recovery_end_timeline</literal></entry>
|
|
<entry><type>integer</type></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>backup_start_lsn</literal></entry>
|
|
<entry><type>pg_lsn</type></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>backup_end_lsn</literal></entry>
|
|
<entry><type>pg_lsn</type></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>end_of_backup_record_required</literal></entry>
|
|
<entry><type>boolean</type></entry>
|
|
</row>
|
|
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
</sect1>
|
|
|
|
<sect1 id="functions-admin">
|
|
<title>System Administration Functions</title>
|
|
|
|
<para>
|
|
The functions described in this section are used to control and
|
|
monitor a <productname>PostgreSQL</productname> installation.
|
|
</para>
|
|
|
|
<sect2 id="functions-admin-set">
|
|
<title>Configuration Settings 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> [, <parameter>missing_ok</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>
|
|
|
|
If there is no setting named <parameter>setting_name</parameter>,
|
|
<function>current_setting</function> throws an error
|
|
unless <parameter>missing_ok</parameter> is supplied and is
|
|
<literal>true</literal>.
|
|
</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>
|
|
|
|
</sect2>
|
|
|
|
<sect2 id="functions-admin-signal">
|
|
<title>Server Signaling Functions</title>
|
|
|
|
<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 by default but access may be granted to others using
|
|
<command>GRANT</command>, with noted exceptions.
|
|
</para>
|
|
|
|
<table id="functions-admin-signal-table">
|
|
<title>Server Signaling 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</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>Cancel a backend's current query. This is also allowed if the
|
|
calling role is a member of the role whose backend is being canceled or
|
|
the calling role has been granted <literal>pg_signal_backend</literal>,
|
|
however only superusers can cancel superuser backends.
|
|
</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</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>Terminate a backend. This is also allowed if the calling role
|
|
is a member of the role whose backend is being terminated or the
|
|
calling role has been granted <literal>pg_signal_backend</literal>,
|
|
however only superusers can terminate superuser backends.
|
|
</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</function> and <function>pg_terminate_backend</function>
|
|
send signals (<systemitem>SIGINT</systemitem> or <systemitem>SIGTERM</systemitem>
|
|
respectively) to backend processes identified by process ID.
|
|
The process ID of an active backend can be found from
|
|
the <structfield>pid</structfield> column of the
|
|
<structname>pg_stat_activity</structname> view, or by listing the
|
|
<command>postgres</command> processes on the server (using
|
|
<application>ps</application> on Unix or the <application>Task
|
|
Manager</application> on <productname>Windows</productname>).
|
|
The role of an active backend can be found from the
|
|
<structfield>usename</structfield> column of the
|
|
<structname>pg_stat_activity</structname> view.
|
|
</para>
|
|
|
|
<para>
|
|
<function>pg_reload_conf</function> sends a <systemitem>SIGHUP</systemitem> signal
|
|
to the server, causing configuration files
|
|
to be reloaded by all server processes.
|
|
</para>
|
|
|
|
<para>
|
|
<function>pg_rotate_logfile</function> 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>
|
|
|
|
</sect2>
|
|
|
|
<sect2 id="functions-admin-backup">
|
|
<title>Backup Control Functions</title>
|
|
|
|
<indexterm>
|
|
<primary>backup</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>pg_create_restore_point</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>pg_current_wal_flush_lsn</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>pg_current_wal_insert_lsn</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>pg_current_wal_lsn</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>pg_start_backup</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>pg_stop_backup</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>pg_is_in_backup</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>pg_backup_start_time</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>pg_switch_wal</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>pg_walfile_name</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>pg_walfile_name_offset</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>pg_wal_lsn_diff</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 (except
|
|
non-exclusive <function>pg_start_backup</function>,
|
|
non-exclusive <function>pg_stop_backup</function>,
|
|
<function>pg_is_in_backup</function>, <function>pg_backup_start_time</function>
|
|
and <function>pg_wal_lsn_diff</function>).
|
|
</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</parameter> <type>text</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>pg_lsn</type></entry>
|
|
<entry>Create a named point for performing restore (restricted to superusers by default, but other users can be granted EXECUTE to run the function)</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_current_wal_flush_lsn()</function></literal>
|
|
</entry>
|
|
<entry><type>pg_lsn</type></entry>
|
|
<entry>Get current write-ahead log flush location</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_current_wal_insert_lsn()</function></literal>
|
|
</entry>
|
|
<entry><type>pg_lsn</type></entry>
|
|
<entry>Get current write-ahead log insert location</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_current_wal_lsn()</function></literal>
|
|
</entry>
|
|
<entry><type>pg_lsn</type></entry>
|
|
<entry>Get current write-ahead log write location</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_start_backup(<parameter>label</parameter> <type>text</type> <optional>, <parameter>fast</parameter> <type>boolean</type> <optional>, <parameter>exclusive</parameter> <type>boolean</type> </optional></optional>)</function></literal>
|
|
</entry>
|
|
<entry><type>pg_lsn</type></entry>
|
|
<entry>Prepare for performing on-line backup (restricted to superusers by default, but other users can be granted EXECUTE to run the function)</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_stop_backup()</function></literal>
|
|
</entry>
|
|
<entry><type>pg_lsn</type></entry>
|
|
<entry>Finish performing exclusive on-line backup (restricted to superusers by default, but other users can be granted EXECUTE to run the function)</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_stop_backup(<parameter>exclusive</parameter> <type>boolean</type> <optional>, <parameter>wait_for_archive</parameter> <type>boolean</type> </optional>)</function></literal>
|
|
</entry>
|
|
<entry><type>setof record</type></entry>
|
|
<entry>Finish performing exclusive or non-exclusive on-line backup (restricted to superusers by default, but other users can be granted EXECUTE to run the function)</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_is_in_backup()</function></literal>
|
|
</entry>
|
|
<entry><type>bool</type></entry>
|
|
<entry>True if an on-line exclusive backup is still in progress.</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_backup_start_time()</function></literal>
|
|
</entry>
|
|
<entry><type>timestamp with time zone</type></entry>
|
|
<entry>Get start time of an on-line exclusive backup in progress.</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_switch_wal()</function></literal>
|
|
</entry>
|
|
<entry><type>pg_lsn</type></entry>
|
|
<entry>Force switch to a new write-ahead log file (restricted to superusers by default, but other users can be granted EXECUTE to run the function)</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_walfile_name(<parameter>lsn</parameter> <type>pg_lsn</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>Convert write-ahead log location to file name</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_walfile_name_offset(<parameter>lsn</parameter> <type>pg_lsn</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>text</type>, <type>integer</type></entry>
|
|
<entry>Convert write-ahead log location to file name and decimal byte offset within file</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_wal_lsn_diff(<parameter>lsn</parameter> <type>pg_lsn</type>, <parameter>lsn</parameter> <type>pg_lsn</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>numeric</type></entry>
|
|
<entry>Calculate the difference between two write-ahead log locations</entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
<function>pg_start_backup</function> accepts an arbitrary user-defined label for
|
|
the backup. (Typically this would be the name under which the backup dump
|
|
file will be stored.) When used in exclusive mode, the function writes a
|
|
backup label file (<filename>backup_label</filename>) and, if there are any links
|
|
in the <filename>pg_tblspc/</filename> directory, a tablespace map file
|
|
(<filename>tablespace_map</filename>) into the database cluster's data directory,
|
|
performs a checkpoint, and then returns the backup's starting write-ahead
|
|
log location as text. The user can ignore this result value, but it is
|
|
provided in case it is useful. When used in non-exclusive mode, the
|
|
contents of these files are instead returned by the
|
|
<function>pg_stop_backup</function> function, and should be written to the backup
|
|
by the caller.
|
|
|
|
<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</literal>,
|
|
it specifies executing <function>pg_start_backup</function> 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>
|
|
In an exclusive backup, <function>pg_stop_backup</function> removes the label file
|
|
and, if it exists, the <filename>tablespace_map</filename> file created by
|
|
<function>pg_start_backup</function>. In a non-exclusive backup, the contents of
|
|
the <filename>backup_label</filename> and <filename>tablespace_map</filename> are returned
|
|
in the result of the function, and should be written to files in the
|
|
backup (and not in the data directory). There is an optional second
|
|
parameter of type <type>boolean</type>. If false, the <function>pg_stop_backup</function>
|
|
will return immediately after the backup is completed without waiting for
|
|
WAL to be archived. This behavior is only useful for backup
|
|
software which independently monitors WAL archiving. Otherwise, WAL
|
|
required to make the backup consistent might be missing and make the backup
|
|
useless. When this parameter is set to true, <function>pg_stop_backup</function>
|
|
will wait for WAL to be archived when archiving is enabled; on the standby,
|
|
this means that it will wait only when <varname>archive_mode = always</varname>.
|
|
If write activity on the primary is low, it may be useful to run
|
|
<function>pg_switch_wal</function> on the primary in order to trigger
|
|
an immediate segment switch.
|
|
</para>
|
|
|
|
<para>
|
|
When executed on a primary, the function also creates a backup history file
|
|
in the write-ahead log
|
|
archive area. The history file includes the label given to
|
|
<function>pg_start_backup</function>, the starting and ending write-ahead log locations for
|
|
the backup, and the starting and ending times of the backup. The return
|
|
value is the backup's ending write-ahead log location (which again
|
|
can be ignored). After recording the ending location, the current
|
|
write-ahead log insertion
|
|
point is automatically advanced to the next write-ahead log file, so that the
|
|
ending write-ahead log file can be archived immediately to complete the backup.
|
|
</para>
|
|
|
|
<para>
|
|
<function>pg_switch_wal</function> moves to the next write-ahead log file, allowing the
|
|
current file to be archived (assuming you are using continuous archiving).
|
|
The return value is the ending write-ahead log location + 1 within the just-completed write-ahead log file.
|
|
If there has been no write-ahead log activity since the last write-ahead log switch,
|
|
<function>pg_switch_wal</function> does nothing and returns the start location
|
|
of the write-ahead log file currently in use.
|
|
</para>
|
|
|
|
<para>
|
|
<function>pg_create_restore_point</function> creates a named write-ahead log
|
|
record that can be used as recovery target, and returns the corresponding
|
|
write-ahead log location. The given name can then be used with
|
|
<xref linkend="guc-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_wal_lsn</function> displays the current write-ahead log write
|
|
location in the same format used by the above functions. Similarly,
|
|
<function>pg_current_wal_insert_lsn</function> displays the current write-ahead log
|
|
insertion location and <function>pg_current_wal_flush_lsn</function> displays the
|
|
current write-ahead log flush location. The insertion location is the <quote>logical</quote>
|
|
end of the write-ahead log at any instant, while the write location is the end of
|
|
what has actually been written out from the server's internal buffers and flush
|
|
location is the location guaranteed to be written to durable storage. 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 write-ahead log
|
|
files. The insertion and flush locations are 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_walfile_name_offset</function> to extract the
|
|
corresponding write-ahead log file name and byte offset from the results of any of the
|
|
above functions. For example:
|
|
<programlisting>
|
|
postgres=# SELECT * FROM pg_walfile_name_offset(pg_stop_backup());
|
|
file_name | file_offset
|
|
--------------------------+-------------
|
|
00000001000000000000000D | 4039624
|
|
(1 row)
|
|
</programlisting>
|
|
Similarly, <function>pg_walfile_name</function> extracts just the write-ahead log file name.
|
|
When the given write-ahead log location is exactly at a write-ahead log file boundary, both
|
|
these functions return the name of the preceding write-ahead log file.
|
|
This is usually the desired behavior for managing write-ahead log archiving
|
|
behavior, since the preceding file is the last one that currently
|
|
needs to be archived.
|
|
</para>
|
|
|
|
<para>
|
|
<function>pg_wal_lsn_diff</function> calculates the difference in bytes
|
|
between two write-ahead log locations. It can be used with
|
|
<structname>pg_stat_replication</structname> or some functions shown in
|
|
<xref linkend="functions-admin-backup-table"/> to get the replication lag.
|
|
</para>
|
|
|
|
<para>
|
|
For details about proper usage of these functions, see
|
|
<xref linkend="continuous-archiving"/>.
|
|
</para>
|
|
|
|
</sect2>
|
|
|
|
<sect2 id="functions-recovery-control">
|
|
<title>Recovery Control Functions</title>
|
|
|
|
<indexterm>
|
|
<primary>pg_is_in_recovery</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>pg_last_wal_receive_lsn</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>pg_last_wal_replay_lsn</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 both during 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_wal_receive_lsn()</function></literal>
|
|
</entry>
|
|
<entry><type>pg_lsn</type></entry>
|
|
<entry>Get last write-ahead 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_wal_replay_lsn()</function></literal>
|
|
</entry>
|
|
<entry><type>pg_lsn</type></entry>
|
|
<entry>Get last write-ahead 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 time stamp of last transaction replayed during recovery.
|
|
This is the time at which the commit or abort WAL record for that
|
|
transaction was generated on the primary.
|
|
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_wal_replay_paused</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>pg_promote</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>pg_wal_replay_pause</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>pg_wal_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_wal_replay_paused()</function></literal>
|
|
</entry>
|
|
<entry><type>bool</type></entry>
|
|
<entry>True if recovery is paused.
|
|
</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_promote(<parameter>wait</parameter> <type>boolean</type> DEFAULT true, <parameter>wait_seconds</parameter> <type>integer</type> DEFAULT 60)</function></literal>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>
|
|
Promotes a physical standby server. With <parameter>wait</parameter>
|
|
set to <literal>true</literal> (the default), the function waits until
|
|
promotion is completed or <parameter>wait_seconds</parameter> seconds
|
|
have passed, and returns <literal>true</literal> if promotion is
|
|
successful and <literal>false</literal> otherwise.
|
|
If <parameter>wait</parameter> is set to <literal>false</literal>, the
|
|
function returns <literal>true</literal> immediately after sending
|
|
<literal>SIGUSR1</literal> to the postmaster to trigger the promotion.
|
|
This function is restricted to superusers by default, but other users
|
|
can be granted EXECUTE to run the function.
|
|
</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_wal_replay_pause()</function></literal>
|
|
</entry>
|
|
<entry><type>void</type></entry>
|
|
<entry>Pauses recovery immediately (restricted to superusers by default, but other users can be granted EXECUTE to run the function).
|
|
</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_wal_replay_resume()</function></literal>
|
|
</entry>
|
|
<entry><type>void</type></entry>
|
|
<entry>Restarts recovery if it was paused (restricted to superusers by default, but other users can be granted EXECUTE to run the function).
|
|
</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>
|
|
|
|
</sect2>
|
|
|
|
<sect2 id="functions-snapshot-synchronization">
|
|
<title>Snapshot Synchronization Functions</title>
|
|
|
|
<indexterm>
|
|
<primary>pg_export_snapshot</primary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
<productname>PostgreSQL</productname> allows database sessions to synchronize their
|
|
snapshots. A <firstterm>snapshot</firstterm> determines which data is visible to the
|
|
transaction that is using the snapshot. Synchronized snapshots are
|
|
necessary when two or more sessions need to see identical content in the
|
|
database. If two sessions just start their transactions independently,
|
|
there is always a possibility that some third transaction commits
|
|
between the executions of the two <command>START TRANSACTION</command> commands,
|
|
so that one session sees the effects of that transaction and the other
|
|
does not.
|
|
</para>
|
|
|
|
<para>
|
|
To solve this problem, <productname>PostgreSQL</productname> allows a transaction to
|
|
<firstterm>export</firstterm> the snapshot it is using. As long as the exporting
|
|
transaction remains open, other transactions can <firstterm>import</firstterm> its
|
|
snapshot, and thereby be guaranteed that they see exactly the same view
|
|
of the database that the first transaction sees. But note that any
|
|
database changes made by any one of these transactions remain invisible
|
|
to the other transactions, as is usual for changes made by uncommitted
|
|
transactions. So the transactions are synchronized with respect to
|
|
pre-existing data, but act normally for changes they make themselves.
|
|
</para>
|
|
|
|
<para>
|
|
Snapshots are exported with the <function>pg_export_snapshot</function> function,
|
|
shown in <xref linkend="functions-snapshot-synchronization-table"/>, and
|
|
imported with the <xref linkend="sql-set-transaction"/> command.
|
|
</para>
|
|
|
|
<table id="functions-snapshot-synchronization-table">
|
|
<title>Snapshot Synchronization 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_export_snapshot()</function></literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>Save the current snapshot and return its identifier</entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
The function <function>pg_export_snapshot</function> saves the current snapshot
|
|
and returns a <type>text</type> string identifying the snapshot. This string
|
|
must be passed (outside the database) to clients that want to import the
|
|
snapshot. The snapshot is available for import only until the end of the
|
|
transaction that exported it. A transaction can export more than one
|
|
snapshot, if needed. Note that doing so is only useful in <literal>READ
|
|
COMMITTED</literal> transactions, since in <literal>REPEATABLE READ</literal> and
|
|
higher isolation levels, transactions use the same snapshot throughout
|
|
their lifetime. Once a transaction has exported any snapshots, it cannot
|
|
be prepared with <xref linkend="sql-prepare-transaction"/>.
|
|
</para>
|
|
|
|
<para>
|
|
See <xref linkend="sql-set-transaction"/> for details of how to use an
|
|
exported snapshot.
|
|
</para>
|
|
</sect2>
|
|
|
|
<sect2 id="functions-replication">
|
|
<title>Replication Functions</title>
|
|
|
|
<para>
|
|
The functions shown
|
|
in <xref linkend="functions-replication-table"/> are for
|
|
controlling and interacting with replication features.
|
|
See <xref linkend="streaming-replication"/>,
|
|
<xref linkend="streaming-replication-slots"/>, and
|
|
<xref linkend="replication-origins"/>
|
|
for information about the underlying features.
|
|
Use of functions for replication origin is restricted to superusers.
|
|
Use of functions for replication slot is restricted to superusers
|
|
and users having <literal>REPLICATION</literal> privilege.
|
|
</para>
|
|
|
|
<para>
|
|
Many of these functions have equivalent commands in the replication
|
|
protocol; see <xref linkend="protocol-replication"/>.
|
|
</para>
|
|
|
|
<para>
|
|
The functions described in
|
|
<xref linkend="functions-admin-backup"/>,
|
|
<xref linkend="functions-recovery-control"/>, and
|
|
<xref linkend="functions-snapshot-synchronization"/>
|
|
are also relevant for replication.
|
|
</para>
|
|
|
|
<table id="functions-replication-table">
|
|
<title>Replication <acronym>SQL</acronym> Functions</title>
|
|
<tgroup cols="3">
|
|
<thead>
|
|
<row>
|
|
<entry>Function</entry>
|
|
<entry>Return Type</entry>
|
|
<entry>Description</entry>
|
|
</row>
|
|
</thead>
|
|
<tbody>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>pg_create_physical_replication_slot</primary>
|
|
</indexterm>
|
|
<literal><function>pg_create_physical_replication_slot(<parameter>slot_name</parameter> <type>name</type> <optional>, <parameter>immediately_reserve</parameter> <type>boolean</type>, <parameter>temporary</parameter> <type>boolean</type></optional>)</function></literal>
|
|
</entry>
|
|
<entry>
|
|
(<parameter>slot_name</parameter> <type>name</type>, <parameter>lsn</parameter> <type>pg_lsn</type>)
|
|
</entry>
|
|
<entry>
|
|
Creates a new physical replication slot named
|
|
<parameter>slot_name</parameter>. The optional second parameter,
|
|
when <literal>true</literal>, specifies that the <acronym>LSN</acronym> for this
|
|
replication slot be reserved immediately; otherwise
|
|
the <acronym>LSN</acronym> is reserved on first connection from a streaming
|
|
replication client. Streaming changes from a physical slot is only
|
|
possible with the streaming-replication protocol —
|
|
see <xref linkend="protocol-replication"/>. The optional third
|
|
parameter, <parameter>temporary</parameter>, when set to true, specifies that
|
|
the slot should not be permanently stored to disk and is only meant
|
|
for use by current session. Temporary slots are also
|
|
released upon any error. This function corresponds
|
|
to the replication protocol command <literal>CREATE_REPLICATION_SLOT
|
|
... PHYSICAL</literal>.
|
|
</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>pg_drop_replication_slot</primary>
|
|
</indexterm>
|
|
<literal><function>pg_drop_replication_slot(<parameter>slot_name</parameter> <type>name</type>)</function></literal>
|
|
</entry>
|
|
<entry>
|
|
<type>void</type>
|
|
</entry>
|
|
<entry>
|
|
Drops the physical or logical replication slot
|
|
named <parameter>slot_name</parameter>. Same as replication protocol
|
|
command <literal>DROP_REPLICATION_SLOT</literal>. For logical slots, this must
|
|
be called when connected to the same database the slot was created on.
|
|
</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>pg_create_logical_replication_slot</primary>
|
|
</indexterm>
|
|
<literal><function>pg_create_logical_replication_slot(<parameter>slot_name</parameter> <type>name</type>, <parameter>plugin</parameter> <type>name</type> <optional>, <parameter>temporary</parameter> <type>boolean</type></optional>)</function></literal>
|
|
</entry>
|
|
<entry>
|
|
(<parameter>slot_name</parameter> <type>name</type>, <parameter>lsn</parameter> <type>pg_lsn</type>)
|
|
</entry>
|
|
<entry>
|
|
Creates a new logical (decoding) replication slot named
|
|
<parameter>slot_name</parameter> using the output plugin
|
|
<parameter>plugin</parameter>. The optional third
|
|
parameter, <parameter>temporary</parameter>, when set to true, specifies that
|
|
the slot should not be permanently stored to disk and is only meant
|
|
for use by current session. Temporary slots are also
|
|
released upon any error. A call to this function has the same
|
|
effect as the replication protocol command
|
|
<literal>CREATE_REPLICATION_SLOT ... LOGICAL</literal>.
|
|
</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>pg_copy_physical_replication_slot</primary>
|
|
</indexterm>
|
|
<literal><function>pg_copy_physical_replication_slot(<parameter>src_slot_name</parameter> <type>name</type>, <parameter>dst_slot_name</parameter> <type>name</type> <optional>, <parameter>temporary</parameter> <type>boolean</type></optional>)</function></literal>
|
|
</entry>
|
|
<entry>
|
|
(<parameter>slot_name</parameter> <type>name</type>, <parameter>lsn</parameter> <type>pg_lsn</type>)
|
|
</entry>
|
|
<entry>
|
|
Copies an existing physical replication slot named <parameter>src_slot_name</parameter>
|
|
to a physical replication slot named <parameter>dst_slot_name</parameter>.
|
|
The copied physical slot starts to reserve WAL from the same <acronym>LSN</acronym> as the
|
|
source slot.
|
|
<parameter>temporary</parameter> is optional. If <parameter>temporary</parameter>
|
|
is omitted, the same value as the source slot is used.
|
|
</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>pg_copy_logical_replication_slot</primary>
|
|
</indexterm>
|
|
<literal><function>pg_copy_logical_replication_slot(<parameter>src_slot_name</parameter> <type>name</type>, <parameter>dst_slot_name</parameter> <type>name</type> <optional>, <parameter>temporary</parameter> <type>boolean</type> <optional>, <parameter>plugin</parameter> <type>name</type></optional></optional>)</function></literal>
|
|
</entry>
|
|
<entry>
|
|
(<parameter>slot_name</parameter> <type>name</type>, <parameter>lsn</parameter> <type>pg_lsn</type>)
|
|
</entry>
|
|
<entry>
|
|
Copies an existing logical replication slot named <parameter>src_slot_name</parameter>
|
|
to a logical replication slot named <parameter>dst_slot_name</parameter>
|
|
while changing the output plugin and persistence. The copied logical slot starts
|
|
from the same <acronym>LSN</acronym> as the source logical slot. Both
|
|
<parameter>temporary</parameter> and <parameter>plugin</parameter> are optional.
|
|
If <parameter>temporary</parameter> or <parameter>plugin</parameter> are omitted,
|
|
the same values as the source logical slot are used.
|
|
</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>pg_logical_slot_get_changes</primary>
|
|
</indexterm>
|
|
<literal><function>pg_logical_slot_get_changes(<parameter>slot_name</parameter> <type>name</type>, <parameter>upto_lsn</parameter> <type>pg_lsn</type>, <parameter>upto_nchanges</parameter> <type>int</type>, VARIADIC <parameter>options</parameter> <type>text[]</type>)</function></literal>
|
|
</entry>
|
|
<entry>
|
|
(<parameter>lsn</parameter> <type>pg_lsn</type>, <parameter>xid</parameter> <type>xid</type>, <parameter>data</parameter> <type>text</type>)
|
|
</entry>
|
|
<entry>
|
|
Returns changes in the slot <parameter>slot_name</parameter>, starting
|
|
from the point at which since changes have been consumed last. If
|
|
<parameter>upto_lsn</parameter> and <parameter>upto_nchanges</parameter> are NULL,
|
|
logical decoding will continue until end of WAL. If
|
|
<parameter>upto_lsn</parameter> is non-NULL, decoding will include only
|
|
those transactions which commit prior to the specified LSN. If
|
|
<parameter>upto_nchanges</parameter> is non-NULL, decoding will
|
|
stop when the number of rows produced by decoding exceeds
|
|
the specified value. Note, however, that the actual number of
|
|
rows returned may be larger, since this limit is only checked after
|
|
adding the rows produced when decoding each new transaction commit.
|
|
</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>pg_logical_slot_peek_changes</primary>
|
|
</indexterm>
|
|
<literal><function>pg_logical_slot_peek_changes(<parameter>slot_name</parameter> <type>name</type>, <parameter>upto_lsn</parameter> <type>pg_lsn</type>, <parameter>upto_nchanges</parameter> <type>int</type>, VARIADIC <parameter>options</parameter> <type>text[]</type>)</function></literal>
|
|
</entry>
|
|
<entry>
|
|
(<parameter>lsn</parameter> <type>pg_lsn</type>, <parameter>xid</parameter> <type>xid</type>, <parameter>data</parameter> <type>text</type>)
|
|
</entry>
|
|
<entry>
|
|
Behaves just like
|
|
the <function>pg_logical_slot_get_changes()</function> function,
|
|
except that changes are not consumed; that is, they will be returned
|
|
again on future calls.
|
|
</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>pg_logical_slot_get_binary_changes</primary>
|
|
</indexterm>
|
|
<literal><function>pg_logical_slot_get_binary_changes(<parameter>slot_name</parameter> <type>name</type>, <parameter>upto_lsn</parameter> <type>pg_lsn</type>, <parameter>upto_nchanges</parameter> <type>int</type>, VARIADIC <parameter>options</parameter> <type>text[]</type>)</function></literal>
|
|
</entry>
|
|
<entry>
|
|
(<parameter>lsn</parameter> <type>pg_lsn</type>, <parameter>xid</parameter> <type>xid</type>, <parameter>data</parameter> <type>bytea</type>)
|
|
</entry>
|
|
<entry>
|
|
Behaves just like
|
|
the <function>pg_logical_slot_get_changes()</function> function,
|
|
except that changes are returned as <type>bytea</type>.
|
|
</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>pg_logical_slot_peek_binary_changes</primary>
|
|
</indexterm>
|
|
<literal><function>pg_logical_slot_peek_binary_changes(<parameter>slot_name</parameter> <type>name</type>, <parameter>upto_lsn</parameter> <type>pg_lsn</type>, <parameter>upto_nchanges</parameter> <type>int</type>, VARIADIC <parameter>options</parameter> <type>text[]</type>)</function></literal>
|
|
</entry>
|
|
<entry>
|
|
(<parameter>lsn</parameter> <type>pg_lsn</type>, <parameter>xid</parameter> <type>xid</type>, <parameter>data</parameter> <type>bytea</type>)
|
|
</entry>
|
|
<entry>
|
|
Behaves just like
|
|
the <function>pg_logical_slot_get_changes()</function> function,
|
|
except that changes are returned as <type>bytea</type> and that
|
|
changes are not consumed; that is, they will be returned again
|
|
on future calls.
|
|
</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>pg_replication_slot_advance</primary>
|
|
</indexterm>
|
|
<literal><function>pg_replication_slot_advance(<parameter>slot_name</parameter> <type>name</type>, <parameter>upto_lsn</parameter> <type>pg_lsn</type>)</function></literal>
|
|
</entry>
|
|
<entry>
|
|
(<parameter>slot_name</parameter> <type>name</type>, <parameter>end_lsn</parameter> <type>pg_lsn</type>)
|
|
<type>bool</type>
|
|
</entry>
|
|
<entry>
|
|
Advances the current confirmed position of a replication slot named
|
|
<parameter>slot_name</parameter>. The slot will not be moved backwards,
|
|
and it will not be moved beyond the current insert location. Returns
|
|
the name of the slot and the real position to which it was advanced to.
|
|
The information of the updated slot is written out at the follow-up
|
|
checkpoint if any advancing is done. In the event of a crash, the
|
|
slot may return to an earlier position.
|
|
</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry id="pg-replication-origin-create">
|
|
<indexterm>
|
|
<primary>pg_replication_origin_create</primary>
|
|
</indexterm>
|
|
<literal><function>pg_replication_origin_create(<parameter>node_name</parameter> <type>text</type>)</function></literal>
|
|
</entry>
|
|
<entry>
|
|
<type>oid</type>
|
|
</entry>
|
|
<entry>
|
|
Create a replication origin with the given external
|
|
name, and return the internal id assigned to it.
|
|
</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry id="pg-replication-origin-drop">
|
|
<indexterm>
|
|
<primary>pg_replication_origin_drop</primary>
|
|
</indexterm>
|
|
<literal><function>pg_replication_origin_drop(<parameter>node_name</parameter> <type>text</type>)</function></literal>
|
|
</entry>
|
|
<entry>
|
|
<type>void</type>
|
|
</entry>
|
|
<entry>
|
|
Delete a previously created replication origin, including any
|
|
associated replay progress.
|
|
</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>pg_replication_origin_oid</primary>
|
|
</indexterm>
|
|
<literal><function>pg_replication_origin_oid(<parameter>node_name</parameter> <type>text</type>)</function></literal>
|
|
</entry>
|
|
<entry>
|
|
<type>oid</type>
|
|
</entry>
|
|
<entry>
|
|
Lookup a replication origin by name and return the internal id. If no
|
|
corresponding replication origin is found an error is thrown.
|
|
</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry id="pg-replication-origin-session-setup">
|
|
<indexterm>
|
|
<primary>pg_replication_origin_session_setup</primary>
|
|
</indexterm>
|
|
<literal><function>pg_replication_origin_session_setup(<parameter>node_name</parameter> <type>text</type>)</function></literal>
|
|
</entry>
|
|
<entry>
|
|
<type>void</type>
|
|
</entry>
|
|
<entry>
|
|
Mark the current session as replaying from the given
|
|
origin, allowing replay progress to be tracked. Use
|
|
<function>pg_replication_origin_session_reset</function> to revert.
|
|
Can only be used if no previous origin is configured.
|
|
</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>pg_replication_origin_session_reset</primary>
|
|
</indexterm>
|
|
<literal><function>pg_replication_origin_session_reset()</function></literal>
|
|
</entry>
|
|
<entry>
|
|
<type>void</type>
|
|
</entry>
|
|
<entry>
|
|
Cancel the effects
|
|
of <function>pg_replication_origin_session_setup()</function>.
|
|
</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>pg_replication_origin_session_is_setup</primary>
|
|
</indexterm>
|
|
<literal><function>pg_replication_origin_session_is_setup()</function></literal>
|
|
</entry>
|
|
<entry>
|
|
<type>bool</type>
|
|
</entry>
|
|
<entry>
|
|
Has a replication origin been configured in the current session?
|
|
</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry id="pg-replication-origin-session-progress">
|
|
<indexterm>
|
|
<primary>pg_replication_origin_session_progress</primary>
|
|
</indexterm>
|
|
<literal><function>pg_replication_origin_session_progress(<parameter>flush</parameter> <type>bool</type>)</function></literal>
|
|
</entry>
|
|
<entry>
|
|
<type>pg_lsn</type>
|
|
</entry>
|
|
<entry>
|
|
Return the replay location for the replication origin configured in
|
|
the current session. The parameter <parameter>flush</parameter>
|
|
determines whether the corresponding local transaction will be
|
|
guaranteed to have been flushed to disk or not.
|
|
</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry id="pg-replication-origin-xact-setup">
|
|
<indexterm>
|
|
<primary>pg_replication_origin_xact_setup</primary>
|
|
</indexterm>
|
|
<literal><function>pg_replication_origin_xact_setup(<parameter>origin_lsn</parameter> <type>pg_lsn</type>, <parameter>origin_timestamp</parameter> <type>timestamptz</type>)</function></literal>
|
|
</entry>
|
|
<entry>
|
|
<type>void</type>
|
|
</entry>
|
|
<entry>
|
|
Mark the current transaction as replaying a transaction that has
|
|
committed at the given <acronym>LSN</acronym> and timestamp. Can
|
|
only be called when a replication origin has previously been
|
|
configured using
|
|
<function>pg_replication_origin_session_setup()</function>.
|
|
</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry id="pg-replication-origin-xact-reset">
|
|
<indexterm>
|
|
<primary>pg_replication_origin_xact_reset</primary>
|
|
</indexterm>
|
|
<literal><function>pg_replication_origin_xact_reset()</function></literal>
|
|
</entry>
|
|
<entry>
|
|
<type>void</type>
|
|
</entry>
|
|
<entry>
|
|
Cancel the effects of
|
|
<function>pg_replication_origin_xact_setup()</function>.
|
|
</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry id="pg-replication-origin-advance">
|
|
<indexterm>
|
|
<primary>pg_replication_origin_advance</primary>
|
|
</indexterm>
|
|
<literal>pg_replication_origin_advance<function>(<parameter>node_name</parameter> <type>text</type>, <parameter>lsn</parameter> <type>pg_lsn</type>)</function></literal>
|
|
</entry>
|
|
<entry>
|
|
<type>void</type>
|
|
</entry>
|
|
<entry>
|
|
Set replication progress for the given node to the given
|
|
location. This primarily is useful for setting up the initial location
|
|
or a new location after configuration changes and similar. Be aware
|
|
that careless use of this function can lead to inconsistently
|
|
replicated data.
|
|
</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry id="pg-replication-origin-progress">
|
|
<indexterm>
|
|
<primary>pg_replication_origin_progress</primary>
|
|
</indexterm>
|
|
<literal><function>pg_replication_origin_progress(<parameter>node_name</parameter> <type>text</type>, <parameter>flush</parameter> <type>bool</type>)</function></literal>
|
|
</entry>
|
|
<entry>
|
|
<type>pg_lsn</type>
|
|
</entry>
|
|
<entry>
|
|
Return the replay location for the given replication origin. The
|
|
parameter <parameter>flush</parameter> determines whether the
|
|
corresponding local transaction will be guaranteed to have been
|
|
flushed to disk or not.
|
|
</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry id="pg-logical-emit-message-text">
|
|
<indexterm>
|
|
<primary>pg_logical_emit_message</primary>
|
|
</indexterm>
|
|
<literal><function>pg_logical_emit_message(<parameter>transactional</parameter> <type>bool</type>, <parameter>prefix</parameter> <type>text</type>, <parameter>content</parameter> <type>text</type>)</function></literal>
|
|
</entry>
|
|
<entry>
|
|
<type>pg_lsn</type>
|
|
</entry>
|
|
<entry>
|
|
Emit text logical decoding message. This can be used to pass generic
|
|
messages to logical decoding plugins through WAL. The parameter
|
|
<parameter>transactional</parameter> specifies if the message should
|
|
be part of current transaction or if it should be written immediately
|
|
and decoded as soon as the logical decoding reads the record. The
|
|
<parameter>prefix</parameter> is textual prefix used by the logical
|
|
decoding plugins to easily recognize interesting messages for them.
|
|
The <parameter>content</parameter> is the text of the message.
|
|
</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry id="pg-logical-emit-message-bytea">
|
|
<literal><function>pg_logical_emit_message(<parameter>transactional</parameter> <type>bool</type>, <parameter>prefix</parameter> <type>text</type>, <parameter>content</parameter> <type>bytea</type>)</function></literal>
|
|
</entry>
|
|
<entry>
|
|
<type>pg_lsn</type>
|
|
</entry>
|
|
<entry>
|
|
Emit binary logical decoding message. This can be used to pass generic
|
|
messages to logical decoding plugins through WAL. The parameter
|
|
<parameter>transactional</parameter> specifies if the message should
|
|
be part of current transaction or if it should be written immediately
|
|
and decoded as soon as the logical decoding reads the record. The
|
|
<parameter>prefix</parameter> is textual prefix used by the logical
|
|
decoding plugins to easily recognize interesting messages for them.
|
|
The <parameter>content</parameter> is the binary content of the
|
|
message.
|
|
</entry>
|
|
</row>
|
|
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
</sect2>
|
|
|
|
<sect2 id="functions-admin-dbobject">
|
|
<title>Database Object Management Functions</title>
|
|
|
|
<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_bytes</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>, <literal>'vm'</literal>, or <literal>'init'</literal>)
|
|
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_bytes(<type>text</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>bigint</type></entry>
|
|
<entry>
|
|
Converts a size in human-readable format with size units into bytes
|
|
</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 expressed as a 64-bit integer into a
|
|
human-readable format with size units
|
|
</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_size_pretty(<type>numeric</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>
|
|
Converts a size in bytes expressed as a numeric value 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</acronym> data
|
|
</entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
<function>pg_column_size</function> shows the space used to store any individual
|
|
data value.
|
|
</para>
|
|
|
|
<para>
|
|
<function>pg_total_relation_size</function> 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>+</literal> <function>pg_indexes_size</function>.
|
|
</para>
|
|
|
|
<para>
|
|
<function>pg_table_size</function> 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</function> 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</function>
|
|
accept the OID or name of a database or tablespace, and return the total
|
|
disk space used therein. To use <function>pg_database_size</function>,
|
|
you must have <literal>CONNECT</literal> permission on the specified database
|
|
(which is granted by default), or be a member of the <literal>pg_read_all_stats</literal>
|
|
role. To use <function>pg_tablespace_size</function>, you must have
|
|
<literal>CREATE</literal> permission on the specified tablespace, or be a member
|
|
of the <literal>pg_read_all_stats</literal> role unless it is the default tablespace for
|
|
the current database.
|
|
</para>
|
|
|
|
<para>
|
|
<function>pg_relation_size</function> accepts the OID or name of a table, index
|
|
or toast table, and returns the on-disk size in bytes of one fork of
|
|
that relation. (Note that for most purposes it is more convenient to
|
|
use the higher-level functions <function>pg_total_relation_size</function>
|
|
or <function>pg_table_size</function>, which sum the sizes of all forks.)
|
|
With one argument, it returns the size of the main data fork of the
|
|
relation. The second argument can be provided to specify which fork
|
|
to examine:
|
|
<itemizedlist spacing="compact">
|
|
<listitem>
|
|
<para>
|
|
<literal>'main'</literal> returns the size of the main
|
|
data fork of the relation.
|
|
</para>
|
|
</listitem>
|
|
<listitem>
|
|
<para>
|
|
<literal>'fsm'</literal> returns the size of the Free Space Map
|
|
(see <xref linkend="storage-fsm"/>) associated with the relation.
|
|
</para>
|
|
</listitem>
|
|
<listitem>
|
|
<para>
|
|
<literal>'vm'</literal> returns the size of the Visibility Map
|
|
(see <xref linkend="storage-vm"/>) associated with the relation.
|
|
</para>
|
|
</listitem>
|
|
<listitem>
|
|
<para>
|
|
<literal>'init'</literal> returns the size of the initialization
|
|
fork, if any, associated with the relation.
|
|
</para>
|
|
</listitem>
|
|
</itemizedlist>
|
|
</para>
|
|
|
|
<para>
|
|
<function>pg_size_pretty</function> can be used to format the result of one of
|
|
the other functions in a human-readable way, using bytes, kB, MB, GB or TB
|
|
as appropriate.
|
|
</para>
|
|
|
|
<para>
|
|
<function>pg_size_bytes</function> can be used to get the size in bytes from a
|
|
string in human-readable format. The input may have units of bytes, kB,
|
|
MB, GB or TB, and is parsed case-insensitively. If no units are specified,
|
|
bytes are assumed.
|
|
</para>
|
|
|
|
<note>
|
|
<para>
|
|
The units kB, MB, GB and TB used by the functions
|
|
<function>pg_size_pretty</function> and <function>pg_size_bytes</function> are defined
|
|
using powers of 2 rather than powers of 10, so 1kB is 1024 bytes, 1MB is
|
|
1024<superscript>2</superscript> = 1048576 bytes, and so on.
|
|
</para>
|
|
</note>
|
|
|
|
<para>
|
|
The functions above that operate on tables or indexes accept a
|
|
<type>regclass</type> argument, which is simply the OID of the table or index
|
|
in the <structname>pg_class</structname> system catalog. You do not have to look up
|
|
the OID by hand, however, since the <type>regclass</type> 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>
|
|
If an OID that does not represent an existing object is passed as
|
|
argument to one of the above functions, NULL is returned.
|
|
</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>
|
|
<indexterm>
|
|
<primary>pg_filenode_relation</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>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_filenode_relation(<parameter>tablespace</parameter> <type>oid</type>, <parameter>filenode</parameter> <type>oid</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>regclass</type></entry>
|
|
<entry>
|
|
Find the relation associated with a given tablespace and filenode
|
|
</entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
<function>pg_relation_filenode</function> accepts the OID or name of a table,
|
|
index, sequence, or toast table, and returns the <quote>filenode</quote> 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</structname>.<structfield>relfilenode</structfield>, but for certain
|
|
system catalogs <structfield>relfilenode</structfield> 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</function> is similar to
|
|
<function>pg_relation_filenode</function>, but it returns the entire file path name
|
|
(relative to the database cluster's data directory <varname>PGDATA</varname>) of
|
|
the relation.
|
|
</para>
|
|
|
|
<para>
|
|
<function>pg_filenode_relation</function> is the reverse of
|
|
<function>pg_relation_filenode</function>. Given a <quote>tablespace</quote> OID and
|
|
a <quote>filenode</quote>, it returns the associated relation's OID. For a table
|
|
in the database's default tablespace, the tablespace can be specified as 0.
|
|
</para>
|
|
|
|
<para>
|
|
<xref linkend="functions-admin-collation"/> lists functions used to manage
|
|
collations.
|
|
</para>
|
|
|
|
<table id="functions-admin-collation">
|
|
<title>Collation Management Functions</title>
|
|
<tgroup cols="3">
|
|
<thead>
|
|
<row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
<row>
|
|
<entry>
|
|
<indexterm><primary>pg_collation_actual_version</primary></indexterm>
|
|
<literal><function>pg_collation_actual_version(<type>oid</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>Return actual version of collation from operating system</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<indexterm><primary>pg_import_system_collations</primary></indexterm>
|
|
<literal><function>pg_import_system_collations(<parameter>schema</parameter> <type>regnamespace</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>integer</type></entry>
|
|
<entry>Import operating system collations</entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
<function>pg_collation_actual_version</function> returns the actual
|
|
version of the collation object as it is currently installed in the
|
|
operating system. If this is different from the value
|
|
in <literal>pg_collation.collversion</literal>, then objects depending on
|
|
the collation might need to be rebuilt. See also
|
|
<xref linkend="sql-altercollation"/>.
|
|
</para>
|
|
|
|
<para>
|
|
<function>pg_import_system_collations</function> adds collations to the system
|
|
catalog <literal>pg_collation</literal> based on all the
|
|
locales it finds in the operating system. This is
|
|
what <command>initdb</command> uses;
|
|
see <xref linkend="collation-managing"/> for more details. If additional
|
|
locales are installed into the operating system later on, this function
|
|
can be run again to add collations for the new locales. Locales that
|
|
match existing entries in <literal>pg_collation</literal> will be skipped.
|
|
(But collation objects based on locales that are no longer
|
|
present in the operating system are not removed by this function.)
|
|
The <parameter>schema</parameter> parameter would typically
|
|
be <literal>pg_catalog</literal>, but that is not a requirement;
|
|
the collations could be installed into some other schema as well.
|
|
The function returns the number of new collation objects it created.
|
|
</para>
|
|
|
|
<table id="functions-info-partition">
|
|
<title>Partitioning Information Functions</title>
|
|
<tgroup cols="3">
|
|
<thead>
|
|
<row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
<row>
|
|
<entry>
|
|
<indexterm><primary>pg_partition_tree</primary></indexterm>
|
|
<literal><function>pg_partition_tree(<type>regclass</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>setof record</type></entry>
|
|
<entry>
|
|
List information about tables or indexes in a partition tree for a
|
|
given partitioned table or partitioned index, with one row for each
|
|
partition. Information provided includes the name of the partition,
|
|
the name of its immediate parent, a boolean value telling if the
|
|
partition is a leaf, and an integer telling its level in the hierarchy.
|
|
The value of level begins at <literal>0</literal> for the input table
|
|
or index in its role as the root of the partition tree,
|
|
<literal>1</literal> for its partitions, <literal>2</literal> for
|
|
their partitions, and so on.
|
|
</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<indexterm><primary>pg_partition_ancestors</primary></indexterm>
|
|
<literal><function>pg_partition_ancestors(<type>regclass</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>setof regclass</type></entry>
|
|
<entry>
|
|
List the ancestor relations of the given partition,
|
|
including the partition itself.
|
|
</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<indexterm><primary>pg_partition_root</primary></indexterm>
|
|
<literal><function>pg_partition_root(<type>regclass</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>regclass</type></entry>
|
|
<entry>
|
|
Return the top-most parent of a partition tree to which the given
|
|
relation belongs.
|
|
</entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
To check the total size of the data contained in
|
|
<structname>measurement</structname> table described in
|
|
<xref linkend="ddl-partitioning-declarative-example"/>, one could use the
|
|
following query:
|
|
</para>
|
|
|
|
<programlisting>
|
|
=# SELECT pg_size_pretty(sum(pg_relation_size(relid))) AS total_size
|
|
FROM pg_partition_tree('measurement');
|
|
total_size
|
|
------------
|
|
24 kB
|
|
(1 row)
|
|
</programlisting>
|
|
|
|
</sect2>
|
|
|
|
<sect2 id="functions-admin-index">
|
|
<title>Index Maintenance Functions</title>
|
|
|
|
<indexterm>
|
|
<primary>brin_summarize_new_values</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>gin_clean_pending_list</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>brin_summarize_range</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>brin_desummarize_range</primary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
<xref linkend="functions-admin-index-table"/> shows the functions
|
|
available for index maintenance tasks.
|
|
These functions cannot be executed during recovery.
|
|
Use of these functions is restricted to superusers and the owner
|
|
of the given index.
|
|
</para>
|
|
|
|
<table id="functions-admin-index-table">
|
|
<title>Index Maintenance Functions</title>
|
|
<tgroup cols="3">
|
|
<thead>
|
|
<row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
<row>
|
|
<entry>
|
|
<literal><function>brin_summarize_new_values(<parameter>index</parameter> <type>regclass</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>integer</type></entry>
|
|
<entry>summarize page ranges not already summarized</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>brin_summarize_range(<parameter>index</parameter> <type>regclass</type>, <parameter>blockNumber</parameter> <type>bigint</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>integer</type></entry>
|
|
<entry>summarize the page range covering the given block, if not already summarized</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>brin_desummarize_range(<parameter>index</parameter> <type>regclass</type>, <parameter>blockNumber</parameter> <type>bigint</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>integer</type></entry>
|
|
<entry>de-summarize the page range covering the given block, if summarized</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>gin_clean_pending_list(<parameter>index</parameter> <type>regclass</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>bigint</type></entry>
|
|
<entry>move GIN pending list entries into main index structure</entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
<function>brin_summarize_new_values</function> accepts the OID or name of a
|
|
BRIN index and inspects the index to find page ranges in the base table
|
|
that are not currently summarized by the index; for any such range
|
|
it creates a new summary index tuple by scanning the table pages.
|
|
It returns the number of new page range summaries that were inserted
|
|
into the index. <function>brin_summarize_range</function> does the same, except
|
|
it only summarizes the range that covers the given block number.
|
|
</para>
|
|
|
|
<para>
|
|
<function>gin_clean_pending_list</function> accepts the OID or name of
|
|
a GIN index and cleans up the pending list of the specified index
|
|
by moving entries in it to the main GIN data structure in bulk.
|
|
It returns the number of pages removed from the pending list.
|
|
Note that if the argument is a GIN index built with
|
|
the <literal>fastupdate</literal> option disabled, no cleanup happens and the
|
|
return value is 0, because the index doesn't have a pending list.
|
|
Please see <xref linkend="gin-fast-update"/> and <xref linkend="gin-tips"/>
|
|
for details of the pending list and <literal>fastupdate</literal> option.
|
|
</para>
|
|
|
|
</sect2>
|
|
|
|
<sect2 id="functions-admin-genfile">
|
|
<title>Generic File Access Functions</title>
|
|
|
|
<para>
|
|
The functions shown in <xref
|
|
linkend="functions-admin-genfile-table"/> provide native access to
|
|
files on the machine hosting the server. Only files within the
|
|
database cluster directory and the <varname>log_directory</varname> can be
|
|
accessed unless the user is granted the role
|
|
<literal>pg_read_server_files</literal>. Use a relative path for files in
|
|
the cluster directory, and a path matching the <varname>log_directory</varname>
|
|
configuration setting for log files.
|
|
</para>
|
|
|
|
<para>
|
|
Note that granting users the EXECUTE privilege on
|
|
<function>pg_read_file()</function>, or related functions, allows them the
|
|
ability to read any file on the server which the database can read and
|
|
that those reads bypass all in-database privilege checks. This means that,
|
|
among other things, a user with this access is able to read the contents of the
|
|
<literal>pg_authid</literal> table where authentication information is contained,
|
|
as well as read any file in the database. Therefore, granting access to these
|
|
functions should be carefully considered.
|
|
</para>
|
|
|
|
<table id="functions-admin-genfile-table">
|
|
<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</parameter> <type>text</type> [, <parameter>missing_ok</parameter> <type>boolean</type>, <parameter>include_dot_dirs</parameter> <type>boolean</type>])</function></literal>
|
|
</entry>
|
|
<entry><type>setof text</type></entry>
|
|
<entry>
|
|
List the contents of a directory. Restricted to superusers by default, but other users can be granted EXECUTE to run the function.
|
|
</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_ls_logdir()</function></literal>
|
|
</entry>
|
|
<entry><type>setof record</type></entry>
|
|
<entry>
|
|
List the name, size, and last modification time of files in the log
|
|
directory. Access is granted to members of the <literal>pg_monitor</literal>
|
|
role and may be granted to other non-superuser roles.
|
|
</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_ls_waldir()</function></literal>
|
|
</entry>
|
|
<entry><type>setof record</type></entry>
|
|
<entry>
|
|
List the name, size, and last modification time of files in the WAL
|
|
directory. Access is granted to members of the <literal>pg_monitor</literal>
|
|
role and may be granted to other non-superuser roles.
|
|
</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_ls_archive_statusdir()</function></literal>
|
|
</entry>
|
|
<entry><type>setof record</type></entry>
|
|
<entry>
|
|
List the name, size, and last modification time of files in the WAL
|
|
archive status directory. Access is granted to members of the
|
|
<literal>pg_monitor</literal> role and may be granted to other
|
|
non-superuser roles.
|
|
</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_ls_tmpdir(<optional><parameter>tablespace</parameter> <type>oid</type></optional>)</function></literal>
|
|
</entry>
|
|
<entry><type>setof record</type></entry>
|
|
<entry>
|
|
List the name, size, and last modification time of files in the
|
|
temporary directory for <parameter>tablespace</parameter>. If
|
|
<parameter>tablespace</parameter> is not provided, the
|
|
<literal>pg_default</literal> tablespace is used. Access is granted
|
|
to members of the <literal>pg_monitor</literal> role and may be
|
|
granted to other non-superuser roles.
|
|
</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_read_file(<parameter>filename</parameter> <type>text</type> [, <parameter>offset</parameter> <type>bigint</type>, <parameter>length</parameter> <type>bigint</type> [, <parameter>missing_ok</parameter> <type>boolean</type>] ])</function></literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>
|
|
Return the contents of a text file. Restricted to superusers by default, but other users can be granted EXECUTE to run the function.
|
|
</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_read_binary_file(<parameter>filename</parameter> <type>text</type> [, <parameter>offset</parameter> <type>bigint</type>, <parameter>length</parameter> <type>bigint</type> [, <parameter>missing_ok</parameter> <type>boolean</type>] ])</function></literal>
|
|
</entry>
|
|
<entry><type>bytea</type></entry>
|
|
<entry>
|
|
Return the contents of a file. Restricted to superusers by default, but other users can be granted EXECUTE to run the function.
|
|
</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_stat_file(<parameter>filename</parameter> <type>text</type>[, <parameter>missing_ok</parameter> <type>boolean</type>])</function></literal>
|
|
</entry>
|
|
<entry><type>record</type></entry>
|
|
<entry>
|
|
Return information about a file. Restricted to superusers by default, but other users can be granted EXECUTE to run the function.
|
|
</entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
Some of these functions take an optional <parameter>missing_ok</parameter> parameter,
|
|
which specifies the behavior when the file or directory does not exist.
|
|
If <literal>true</literal>, the function returns NULL (except
|
|
<function>pg_ls_dir</function>, which returns an empty result set). If
|
|
<literal>false</literal>, an error is raised. The default is <literal>false</literal>.
|
|
</para>
|
|
|
|
<indexterm>
|
|
<primary>pg_ls_dir</primary>
|
|
</indexterm>
|
|
<para>
|
|
<function>pg_ls_dir</function> returns the names of all files (and directories
|
|
and other special files) in the specified directory. The <parameter>
|
|
include_dot_dirs</parameter> indicates whether <quote>.</quote> and <quote>..</quote> are
|
|
included in the result set. The default is to exclude them
|
|
(<literal>false</literal>), but including them can be useful when
|
|
<parameter>missing_ok</parameter> is <literal>true</literal>, to distinguish an
|
|
empty directory from an non-existent directory.
|
|
</para>
|
|
|
|
<indexterm>
|
|
<primary>pg_ls_logdir</primary>
|
|
</indexterm>
|
|
<para>
|
|
<function>pg_ls_logdir</function> returns the name, size, and last modified time
|
|
(mtime) of each file in the log directory. By default, only superusers
|
|
and members of the <literal>pg_monitor</literal> role can use this function.
|
|
Access may be granted to others using <command>GRANT</command>.
|
|
Filenames beginning with a dot, directories, and other special files are not shown.
|
|
</para>
|
|
|
|
<indexterm>
|
|
<primary>pg_ls_waldir</primary>
|
|
</indexterm>
|
|
<para>
|
|
<function>pg_ls_waldir</function> returns the name, size, and last modified time
|
|
(mtime) of each file in the write ahead log (WAL) directory. By
|
|
default only superusers and members of the <literal>pg_monitor</literal> role
|
|
can use this function. Access may be granted to others using
|
|
<command>GRANT</command>.
|
|
Filenames beginning with a dot, directories, and other special files are not shown.
|
|
</para>
|
|
|
|
<indexterm>
|
|
<primary>pg_ls_archive_statusdir</primary>
|
|
</indexterm>
|
|
<para>
|
|
<function>pg_ls_archive_statusdir</function> returns the name, size, and
|
|
last modified time (mtime) of each file in the WAL archive status
|
|
directory <filename>pg_wal/archive_status</filename>. By default only
|
|
superusers and members of the <literal>pg_monitor</literal> role can
|
|
use this function. Access may be granted to others using
|
|
<command>GRANT</command>.
|
|
Filenames beginning with a dot, directories, and other special files are not shown.
|
|
</para>
|
|
|
|
<indexterm>
|
|
<primary>pg_ls_tmpdir</primary>
|
|
</indexterm>
|
|
<para>
|
|
<function>pg_ls_tmpdir</function> returns the name, size, and last modified
|
|
time (mtime) of each file in the temporary file directory for the specified
|
|
<parameter>tablespace</parameter>. If <parameter>tablespace</parameter> is
|
|
not provided, the <literal>pg_default</literal> tablespace is used. By
|
|
default only superusers and members of the <literal>pg_monitor</literal>
|
|
role can use this function. Access may be granted to others using
|
|
<command>GRANT</command>.
|
|
Filenames beginning with a dot, directories, and other special files are not shown.
|
|
</para>
|
|
|
|
<indexterm>
|
|
<primary>pg_read_file</primary>
|
|
</indexterm>
|
|
<para>
|
|
<function>pg_read_file</function> returns part of a text file, starting
|
|
at the given <parameter>offset</parameter>, returning at most <parameter>length</parameter>
|
|
bytes (less if the end of file is reached first). If <parameter>offset</parameter>
|
|
is negative, it is relative to the end of the file.
|
|
If <parameter>offset</parameter> and <parameter>length</parameter> 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</function> is similar to
|
|
<function>pg_read_file</function>, except that the result is a <type>bytea</type> value;
|
|
accordingly, no encoding checks are performed.
|
|
In combination with the <function>convert_from</function> 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</function> 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>
|
|
|
|
</sect2>
|
|
|
|
<sect2 id="functions-advisory-locks">
|
|
<title>Advisory Lock Functions</title>
|
|
|
|
<para>
|
|
The functions shown in <xref linkend="functions-advisory-locks-table"/>
|
|
manage advisory locks. For details about proper use of these functions,
|
|
see <xref linkend="advisory-locks"/>.
|
|
</para>
|
|
|
|
<table id="functions-advisory-locks-table">
|
|
<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</parameter> <type>bigint</type>)</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</parameter> <type>int</type>, <parameter>key2</parameter> <type>int</type>)</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</parameter> <type>bigint</type>)</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</parameter> <type>int</type>, <parameter>key2</parameter> <type>int</type>)</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</parameter> <type>bigint</type>)</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</parameter> <type>int</type>, <parameter>key2</parameter> <type>int</type>)</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</parameter> <type>bigint</type>)</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</parameter> <type>int</type>, <parameter>key2</parameter> <type>int</type>)</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</parameter> <type>bigint</type>)</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</parameter> <type>int</type>, <parameter>key2</parameter> <type>int</type>)</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</parameter> <type>bigint</type>)</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</parameter> <type>int</type>, <parameter>key2</parameter> <type>int</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>void</type></entry>
|
|
<entry>Obtain shared transaction level advisory lock</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_try_advisory_lock(<parameter>key</parameter> <type>bigint</type>)</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</parameter> <type>int</type>, <parameter>key2</parameter> <type>int</type>)</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</parameter> <type>bigint</type>)</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</parameter> <type>int</type>, <parameter>key2</parameter> <type>int</type>)</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</parameter> <type>bigint</type>)</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</parameter> <type>int</type>, <parameter>key2</parameter> <type>int</type>)</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</parameter> <type>bigint</type>)</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</parameter> <type>int</type>, <parameter>key2</parameter> <type>int</type>)</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</function> 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).
|
|
If another session already holds a lock on the same resource identifier,
|
|
this 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 then be 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</function> works the same as
|
|
<function>pg_advisory_lock</function>,
|
|
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</function> is similar to
|
|
<function>pg_advisory_lock</function>, except the function will not wait for the
|
|
lock to become available. It will either obtain the lock immediately and
|
|
return <literal>true</literal>, or return <literal>false</literal> if the lock cannot be
|
|
acquired immediately.
|
|
</para>
|
|
|
|
<indexterm>
|
|
<primary>pg_try_advisory_lock_shared</primary>
|
|
</indexterm>
|
|
<para>
|
|
<function>pg_try_advisory_lock_shared</function> works the same as
|
|
<function>pg_try_advisory_lock</function>, except it attempts to acquire
|
|
a shared rather than an exclusive lock.
|
|
</para>
|
|
|
|
<indexterm>
|
|
<primary>pg_advisory_unlock</primary>
|
|
</indexterm>
|
|
<para>
|
|
<function>pg_advisory_unlock</function> will release a previously-acquired
|
|
exclusive session level advisory lock. It
|
|
returns <literal>true</literal> if the lock is successfully released.
|
|
If the lock was not held, it will return <literal>false</literal>,
|
|
and in addition, an SQL warning will be reported by the server.
|
|
</para>
|
|
|
|
<indexterm>
|
|
<primary>pg_advisory_unlock_shared</primary>
|
|
</indexterm>
|
|
<para>
|
|
<function>pg_advisory_unlock_shared</function> works the same as
|
|
<function>pg_advisory_unlock</function>,
|
|
except it releases a shared session level advisory lock.
|
|
</para>
|
|
|
|
<indexterm>
|
|
<primary>pg_advisory_unlock_all</primary>
|
|
</indexterm>
|
|
<para>
|
|
<function>pg_advisory_unlock_all</function> 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>
|
|
|
|
<indexterm>
|
|
<primary>pg_advisory_xact_lock</primary>
|
|
</indexterm>
|
|
<para>
|
|
<function>pg_advisory_xact_lock</function> works the same as
|
|
<function>pg_advisory_lock</function>, except the lock is automatically released
|
|
at the end of the current transaction and cannot be released explicitly.
|
|
</para>
|
|
|
|
<indexterm>
|
|
<primary>pg_advisory_xact_lock_shared</primary>
|
|
</indexterm>
|
|
<para>
|
|
<function>pg_advisory_xact_lock_shared</function> works the same as
|
|
<function>pg_advisory_lock_shared</function>, except the lock is automatically released
|
|
at the end of the current transaction and cannot be released explicitly.
|
|
</para>
|
|
|
|
<indexterm>
|
|
<primary>pg_try_advisory_xact_lock</primary>
|
|
</indexterm>
|
|
<para>
|
|
<function>pg_try_advisory_xact_lock</function> works the same as
|
|
<function>pg_try_advisory_lock</function>, except the lock, if acquired,
|
|
is automatically released at the end of the current transaction and
|
|
cannot be released explicitly.
|
|
</para>
|
|
|
|
<indexterm>
|
|
<primary>pg_try_advisory_xact_lock_shared</primary>
|
|
</indexterm>
|
|
<para>
|
|
<function>pg_try_advisory_xact_lock_shared</function> works the same as
|
|
<function>pg_try_advisory_lock_shared</function>, except the lock, if acquired,
|
|
is automatically released at the end of the current transaction and
|
|
cannot be released explicitly.
|
|
</para>
|
|
|
|
</sect2>
|
|
|
|
</sect1>
|
|
|
|
<sect1 id="functions-trigger">
|
|
<title>Trigger Functions</title>
|
|
|
|
<indexterm>
|
|
<primary>suppress_redundant_updates_trigger</primary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
Currently <productname>PostgreSQL</productname> provides one built in trigger
|
|
function, <function>suppress_redundant_updates_trigger</function>,
|
|
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</function>, 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> function can be
|
|
added to a table like this:
|
|
<programlisting>
|
|
CREATE TRIGGER z_min_update
|
|
BEFORE UPDATE ON tablename
|
|
FOR EACH ROW EXECUTE FUNCTION 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>
|
|
|
|
<sect1 id="functions-event-triggers">
|
|
<title>Event Trigger Functions</title>
|
|
|
|
<para>
|
|
<productname>PostgreSQL</productname> provides these helper functions
|
|
to retrieve information from event triggers.
|
|
</para>
|
|
|
|
<para>
|
|
For more information about event triggers,
|
|
see <xref linkend="event-triggers"/>.
|
|
</para>
|
|
|
|
<sect2 id="pg-event-trigger-ddl-command-end-functions">
|
|
<title>Capturing Changes at Command End</title>
|
|
|
|
<indexterm>
|
|
<primary>pg_event_trigger_ddl_commands</primary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
<function>pg_event_trigger_ddl_commands</function> returns a list of
|
|
<acronym>DDL</acronym> commands executed by each user action,
|
|
when invoked in a function attached to a
|
|
<literal>ddl_command_end</literal> event trigger. If called in any other
|
|
context, an error is raised.
|
|
<function>pg_event_trigger_ddl_commands</function> returns one row for each
|
|
base command executed; some commands that are a single SQL sentence
|
|
may return more than one row. This function returns the following
|
|
columns:
|
|
|
|
<informaltable>
|
|
<tgroup cols="3">
|
|
<thead>
|
|
<row>
|
|
<entry>Name</entry>
|
|
<entry>Type</entry>
|
|
<entry>Description</entry>
|
|
</row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
<row>
|
|
<entry><literal>classid</literal></entry>
|
|
<entry><type>oid</type></entry>
|
|
<entry>OID of catalog the object belongs in</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>objid</literal></entry>
|
|
<entry><type>oid</type></entry>
|
|
<entry>OID of the object itself</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>objsubid</literal></entry>
|
|
<entry><type>integer</type></entry>
|
|
<entry>Sub-object ID (e.g. attribute number for a column)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>command_tag</literal></entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>Command tag</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>object_type</literal></entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>Type of the object</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>schema_name</literal></entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>
|
|
Name of the schema the object belongs in, if any; otherwise <literal>NULL</literal>.
|
|
No quoting is applied.
|
|
</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>object_identity</literal></entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>
|
|
Text rendering of the object identity, schema-qualified. Each
|
|
identifier included in the identity is quoted if necessary.
|
|
</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>in_extension</literal></entry>
|
|
<entry><type>bool</type></entry>
|
|
<entry>True if the command is part of an extension script</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>command</literal></entry>
|
|
<entry><type>pg_ddl_command</type></entry>
|
|
<entry>
|
|
A complete representation of the command, in internal format.
|
|
This cannot be output directly, but it can be passed to other
|
|
functions to obtain different pieces of information about the
|
|
command.
|
|
</entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</informaltable>
|
|
</para>
|
|
</sect2>
|
|
|
|
<sect2 id="pg-event-trigger-sql-drop-functions">
|
|
<title>Processing Objects Dropped by a DDL Command</title>
|
|
|
|
<indexterm>
|
|
<primary>pg_event_trigger_dropped_objects</primary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
<function>pg_event_trigger_dropped_objects</function> returns a list of all objects
|
|
dropped by the command in whose <literal>sql_drop</literal> event it is called.
|
|
If called in any other context,
|
|
<function>pg_event_trigger_dropped_objects</function> raises an error.
|
|
<function>pg_event_trigger_dropped_objects</function> returns the following columns:
|
|
|
|
<informaltable>
|
|
<tgroup cols="3">
|
|
<thead>
|
|
<row>
|
|
<entry>Name</entry>
|
|
<entry>Type</entry>
|
|
<entry>Description</entry>
|
|
</row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
<row>
|
|
<entry><literal>classid</literal></entry>
|
|
<entry><type>oid</type></entry>
|
|
<entry>OID of catalog the object belonged in</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>objid</literal></entry>
|
|
<entry><type>oid</type></entry>
|
|
<entry>OID of the object itself</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>objsubid</literal></entry>
|
|
<entry><type>integer</type></entry>
|
|
<entry>Sub-object ID (e.g. attribute number for a column)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>original</literal></entry>
|
|
<entry><type>bool</type></entry>
|
|
<entry>True if this was one of the root object(s) of the deletion</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>normal</literal></entry>
|
|
<entry><type>bool</type></entry>
|
|
<entry>
|
|
True if there was a normal dependency relationship
|
|
in the dependency graph leading to this object
|
|
</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>is_temporary</literal></entry>
|
|
<entry><type>bool</type></entry>
|
|
<entry>
|
|
True if this was a temporary object
|
|
</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>object_type</literal></entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>Type of the object</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>schema_name</literal></entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>
|
|
Name of the schema the object belonged in, if any; otherwise <literal>NULL</literal>.
|
|
No quoting is applied.
|
|
</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>object_name</literal></entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>
|
|
Name of the object, if the combination of schema and name can be
|
|
used as a unique identifier for the object; otherwise <literal>NULL</literal>.
|
|
No quoting is applied, and name is never schema-qualified.
|
|
</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>object_identity</literal></entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>
|
|
Text rendering of the object identity, schema-qualified. Each
|
|
identifier included in the identity is quoted if necessary.
|
|
</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>address_names</literal></entry>
|
|
<entry><type>text[]</type></entry>
|
|
<entry>
|
|
An array that, together with <literal>object_type</literal> and
|
|
<literal>address_args</literal>, can be used by
|
|
the <function>pg_get_object_address()</function> function to
|
|
recreate the object address in a remote server containing an
|
|
identically named object of the same kind
|
|
</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>address_args</literal></entry>
|
|
<entry><type>text[]</type></entry>
|
|
<entry>
|
|
Complement for <literal>address_names</literal>
|
|
</entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</informaltable>
|
|
</para>
|
|
|
|
<para>
|
|
The <function>pg_event_trigger_dropped_objects</function> function can be used
|
|
in an event trigger like this:
|
|
<programlisting>
|
|
CREATE FUNCTION test_event_trigger_for_drops()
|
|
RETURNS event_trigger LANGUAGE plpgsql AS $$
|
|
DECLARE
|
|
obj record;
|
|
BEGIN
|
|
FOR obj IN SELECT * FROM pg_event_trigger_dropped_objects()
|
|
LOOP
|
|
RAISE NOTICE '% dropped object: % %.% %',
|
|
tg_tag,
|
|
obj.object_type,
|
|
obj.schema_name,
|
|
obj.object_name,
|
|
obj.object_identity;
|
|
END LOOP;
|
|
END
|
|
$$;
|
|
CREATE EVENT TRIGGER test_event_trigger_for_drops
|
|
ON sql_drop
|
|
EXECUTE FUNCTION test_event_trigger_for_drops();
|
|
</programlisting>
|
|
</para>
|
|
</sect2>
|
|
|
|
<sect2 id="pg-event-trigger-table-rewrite-functions">
|
|
<title>Handling a Table Rewrite Event</title>
|
|
|
|
<para>
|
|
The functions shown in
|
|
<xref linkend="functions-event-trigger-table-rewrite"/>
|
|
provide information about a table for which a
|
|
<literal>table_rewrite</literal> event has just been called.
|
|
If called in any other context, an error is raised.
|
|
</para>
|
|
|
|
<table id="functions-event-trigger-table-rewrite">
|
|
<title>Table Rewrite Information</title>
|
|
<tgroup cols="3">
|
|
<thead>
|
|
<row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
<row>
|
|
<entry>
|
|
<indexterm><primary>pg_event_trigger_table_rewrite_oid</primary></indexterm>
|
|
<literal><function>pg_event_trigger_table_rewrite_oid()</function></literal>
|
|
</entry>
|
|
<entry><type>Oid</type></entry>
|
|
<entry>The OID of the table about to be rewritten.</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm><primary>pg_event_trigger_table_rewrite_reason</primary></indexterm>
|
|
<literal><function>pg_event_trigger_table_rewrite_reason()</function></literal>
|
|
</entry>
|
|
<entry><type>int</type></entry>
|
|
<entry>
|
|
The reason code(s) explaining the reason for rewriting. The exact
|
|
meaning of the codes is release dependent.
|
|
</entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
The <function>pg_event_trigger_table_rewrite_oid</function> function can be used
|
|
in an event trigger like this:
|
|
<programlisting>
|
|
CREATE FUNCTION test_event_trigger_table_rewrite_oid()
|
|
RETURNS event_trigger
|
|
LANGUAGE plpgsql AS
|
|
$$
|
|
BEGIN
|
|
RAISE NOTICE 'rewriting table % for reason %',
|
|
pg_event_trigger_table_rewrite_oid()::regclass,
|
|
pg_event_trigger_table_rewrite_reason();
|
|
END;
|
|
$$;
|
|
|
|
CREATE EVENT TRIGGER test_table_rewrite_oid
|
|
ON table_rewrite
|
|
EXECUTE FUNCTION test_event_trigger_table_rewrite_oid();
|
|
</programlisting>
|
|
</para>
|
|
</sect2>
|
|
</sect1>
|
|
|
|
<sect1 id="functions-statistics">
|
|
<title>Statistics Information Functions</title>
|
|
|
|
<indexterm zone="functions-statistics">
|
|
<primary>function</primary>
|
|
<secondary>statistics</secondary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
<productname>PostgreSQL</productname> provides a function to inspect complex
|
|
statistics defined using the <command>CREATE STATISTICS</command> command.
|
|
</para>
|
|
|
|
<sect2 id="functions-statistics-mcv">
|
|
<title>Inspecting MCV Lists</title>
|
|
|
|
<indexterm>
|
|
<primary>pg_mcv_list_items</primary>
|
|
<secondary>pg_mcv_list</secondary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
<function>pg_mcv_list_items</function> returns a list of all items
|
|
stored in a multi-column <acronym>MCV</acronym> list, and returns the
|
|
following columns:
|
|
|
|
<informaltable>
|
|
<tgroup cols="3">
|
|
<thead>
|
|
<row>
|
|
<entry>Name</entry>
|
|
<entry>Type</entry>
|
|
<entry>Description</entry>
|
|
</row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
<row>
|
|
<entry><literal>index</literal></entry>
|
|
<entry><type>int</type></entry>
|
|
<entry>index of the item in the <acronym>MCV</acronym> list</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>values</literal></entry>
|
|
<entry><type>text[]</type></entry>
|
|
<entry>values stored in the MCV item</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>nulls</literal></entry>
|
|
<entry><type>boolean[]</type></entry>
|
|
<entry>flags identifying <literal>NULL</literal> values</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>frequency</literal></entry>
|
|
<entry><type>double precision</type></entry>
|
|
<entry>frequency of this <acronym>MCV</acronym> item</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>base_frequency</literal></entry>
|
|
<entry><type>double precision</type></entry>
|
|
<entry>base frequency of this <acronym>MCV</acronym> item</entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</informaltable>
|
|
</para>
|
|
|
|
<para>
|
|
The <function>pg_mcv_list_items</function> function can be used like this:
|
|
|
|
<programlisting>
|
|
SELECT m.* FROM pg_statistic_ext join pg_statistic_ext_data on (oid = stxoid),
|
|
pg_mcv_list_items(stxdmcv) m WHERE stxname = 'stts';
|
|
</programlisting>
|
|
|
|
Values of the <type>pg_mcv_list</type> can be obtained only from the
|
|
<literal>pg_statistic_ext_data.stxdmcv</literal> column.
|
|
</para>
|
|
</sect2>
|
|
|
|
</sect1>
|
|
|
|
</chapter>
|