postgresql/doc/src/sgml/func.sgml

3591 lines
107 KiB
Plaintext
Raw Normal View History

<!-- $Header: /cvsroot/pgsql/doc/src/sgml/func.sgml,v 1.53 2001/02/19 00:01:18 tgl Exp $ -->
<chapter id="functions">
<title>Functions and Operators</title>
<para>
<productname>Postgres</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 the
<citetitle>Programmer's Guide</citetitle>. The
<application>psql</application> commands <command>\df</command> and
<command>\do</command> can be used to show the list of all actually
available functions and operators, respectively.
</para>
<para>
If you are concerned about portability then take 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. However, many other <acronym>RDBMS</acronym> packages provide a lot of the
same or similar functions, and some of the ones provided in
<productname>Postgres</productname> have in fact been inspired by
other implementations.
</para>
<sect1 id="functions-logical">
<title>Logical Operators</title>
<para>
The usual logical operators are available:
<simplelist>
<member>AND</member>
<member>OR</member>
<member>NOT</member>
</simplelist>
<acronym>SQL</acronym> uses a three-valued Boolean logic where NULL 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>
</sect1>
<sect1 id="functions-comparison">
<title>Comparison Operators</title>
<table>
<title>Comparison Operators</TITLE>
<tgroup cols="2">
<thead>
<row>
<entry>Operator</entry>
<entry>Description</entry>
</row>
</thead>
<tbody>
<row>
<entry> <literal>&lt;</literal> </entry>
<entry>less than</entry>
</row>
<row>
<entry> <literal>&gt;</literal> </entry>
<entry>greater than</entry>
</row>
<row>
<entry> <literal>&lt;=</literal> </entry>
<entry>less than or equal to</entry>
</row>
<row>
<entry> <literal>&gt;=</literal> </entry>
<entry>greater than or equal to</entry>
</row>
<row>
<entry> <literal>=</literal> </entry>
<entry>equal</entry>
</row>
<row>
<entry> <literal>&lt;&gt;</literal> or <literal>!=</literal> </entry>
<entry>not equal</entry>
</row>
</tbody>
</tgroup>
</table>
<note>
1999-06-14 09:36:12 +02:00
<para>
The <literal>!=</literal> operator is converted to
<literal>&lt;&gt;</literal> in the parser stage. It is not
possible to implement <literal>!=</literal> and
<literal>&lt;&gt;</literal> operators that do different things.
1999-06-14 09:36:12 +02:00
</para>
</note>
<para>
Comparison operators are available for all data types where this
makes sense. All comparison operators are binary operators that
return values of type <type>boolean</type>; expressions like
<literal>1 &lt; 2 &lt; 3</literal> are not valid (because there is
no <literal>&lt;</literal> operator to compare a Boolean value with
<literal>3</literal>).
</para>
2001-02-05 20:21:45 +01:00
<para>
In addition to the comparison operators, the special
<token>BETWEEN</token> construct is available.
<synopsis>
<replaceable>a</replaceable> BETWEEN <replaceable>x</replaceable> AND <replaceable>y</replaceable>
</synopsis>
is equivalent to
<synopsis>
<replaceable>a</replaceable> &gt;= <replaceable>x</replaceable> AND <replaceable>a</replaceable> &lt;= <replaceable>y</replaceable>
</synopsis>
Similarly,
<synopsis>
<replaceable>a</replaceable> NOT BETWEEN <replaceable>x</replaceable> AND <replaceable>y</replaceable>
</synopsis>
is equivalent to
<synopsis>
<replaceable>a</replaceable> &lt; <replaceable>x</replaceable> OR <replaceable>a</replaceable> &gt; <replaceable>y</replaceable>
</synopsis>
There is no difference between the two respective forms apart from
the <acronym>CPU</acronym> cycles required to rewrite the first one
into the second one internally.
</para>
<para>
To check whether a value is or is not NULL, use the constructs
<synopsis>
<replaceable>expression</replaceable> IS NULL
<replaceable>expression</replaceable> IS NOT NULL
</synopsis>
Do <emphasis>not</emphasis> use
<literal><replaceable>expression</replaceable> = NULL</literal>
because NULL is not <quote>equal to</quote> NULL. (NULL represents
an unknown value, so it is not known whether two unknown values are
equal.) <productname>Postgres</productname> presently converts
<literal>x = NULL</literal> clauses to <literal>x IS NULL</literal> to
allow some broken client applications (such as
<productname>Microsoft Access</productname>) to work, but this may
be discontinued in a future release.
</para>
</sect1>
<sect1 id="functions-math">
<title>Mathematical Functions and Operators</title>
<table>
<title>Mathematical Operators</TITLE>
<tgroup cols="4">
<thead>
<row>
<entry>Name</entry>
<entry>Description</entry>
<entry>Example</entry>
<entry>Result</entry>
</row>
</thead>
<tbody>
<row>
<entry> <literal>+</literal> </entry>
<entry>Addition</entry>
<entry>2 + 3</entry>
<entry>5</entry>
</row>
<row>
<entry> <literal>-</literal> </entry>
<entry>Subtraction</entry>
<entry>2 - 3</entry>
<entry>-1</entry>
</row>
<row>
<entry> <literal>*</literal> </entry>
<entry>Multiplication</entry>
<entry>2 * 3</entry>
<entry>6</entry>
</row>
<row>
<entry> <literal>/</literal> </entry>
<entry>Division (integer division truncates results)</entry>
<entry>4 / 2</entry>
<entry>2</entry>
</row>
<row>
<entry> <literal>%</literal> </entry>
<entry>Modulo (remainder)</entry>
<entry>5 % 4</entry>
<entry>1</entry>
</row>
<row>
<entry> <literal>^</literal> </entry>
<entry>Exponentiation</entry>
<entry>2.0 ^ 3.0</entry>
<entry>8.0</entry>
</row>
<row>
<entry> <literal>|/</literal> </entry>
<entry>Square root</entry>
<entry>|/ 25.0</entry>
<entry>5.0</entry>
</row>
<row>
<entry> <literal>||/</literal> </entry>
<entry>Cube root</entry>
<entry>||/ 27.0</entry>
<entry>3</entry>
</row>
<row>
<entry> <literal>!</literal> </entry>
<entry>Factorial</entry>
<entry>5 !</entry>
<entry>120</entry>
</row>
<row>
<entry> <literal>!!</literal> </entry>
<entry>Factorial (prefix operator)</entry>
<entry>!! 5</entry>
<entry>120</entry>
</row>
<row>
<entry> <literal>@</literal> </entry>
<entry>Absolute value</entry>
<entry>@ -5.0</entry>
<entry>5.0</entry>
</row>
<row>
<entry> <literal>&amp;</literal> </entry>
<entry>Binary AND</entry>
<entry>91 & 15</entry>
<entry>11</entry>
</row>
<row>
<entry> <literal>|</literal> </entry>
<entry>Binary OR</entry>
<entry>32 | 3</entry>
<entry>35</entry>
</row>
<row>
<entry> <literal>#</literal> </entry>
<entry>Binary XOR</entry>
<entry>17 # 5</entry>
<entry>20</entry>
</row>
<row>
<entry> <literal>~</literal> </entry>
<entry>Binary NOT</entry>
<entry>~1</entry>
<entry>-2</entry>
</row>
<row>
<entry> &lt;&lt; </entry>
<entry>Binary shift left</entry>
<entry>1 &lt;&lt; 4</entry>
<entry>16</entry>
</row>
<row>
<entry> &gt;&gt; </entry>
<entry>Binary shift right</entry>
<entry>8 &gt;&gt; 2</entry>
<entry>2</entry>
</row>
</tbody>
</tgroup>
</table>
<para>
The <quote>binary</quote> operators are also available for the bit
string types <type>BIT</type> and <type>BIT VARYING</type>.
<table>
<title>Bit String Binary Operators</title>
<tgroup cols="2">
<thead>
<row>
<entry>Example</entry>
<entry>Result</entry>
</row>
</thead>
<tbody>
<row>
<entry>B'10001' & B'01101'</entry>
<entry>00001</entry>
</row>
<row>
<entry>B'10001' | B'01101'</entry>
<entry>11101</entry>
</row>
<row>
<entry>B'10001' # B'01101'</entry>
<entry>11110</entry>
</row>
<row>
<entry>~ B'10001'</entry>
<entry>01110</entry>
</row>
<row>
<entry>B'10001' << 3</entry>
<entry>01000</entry>
</row>
<row>
<entry>B'10001' >> 2</entry>
<entry>00100</entry>
</row>
</tbody>
</tgroup>
</table>
Bit string arguments to <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
here.
</para>
<table tocentry="1">
<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>abs(<replaceable>x</replaceable>)</entry>
<entry>(same as argument type)</entry>
<entry>absolute value</entry>
<entry>abs(-17.4)</entry>
<entry>17.4</entry>
</row>
<row>
<entry>cbrt(<type>double precision</type>)</entry>
<entry><type>double precision</type></entry>
<entry>cube root</entry>
<entry>cbrt(27.0)</entry>
2000-12-19 18:35:46 +01:00
<entry>3.0</entry>
</row>
<row>
<entry>ceil(<type>numeric</type>)</entry>
<entry><type>numeric</type></entry>
<entry>smallest integer not less than argument</entry>
<entry>ceil(-42.8)</entry>
<entry>-42</entry>
</row>
<row>
<entry>degrees(<type>double precision</type>)</entry>
<entry><type>double precision</type></entry>
<entry>convert radians to degrees</entry>
<entry>degrees(0.5)</entry>
<entry>28.6478897565412</entry>
</row>
<row>
<entry>exp(<type>double precision</type>)</entry>
<entry><type>double precision</type></entry>
<entry>exponential function</entry>
<entry>exp(1.0)</entry>
<entry>2.71828182845905</entry>
</row>
<row>
<entry>floor(<type>numeric</type>)</entry>
<entry><type>numeric</type></entry>
<entry>largest integer not greater than argument</entry>
<entry>floor(-42.8)</entry>
2000-12-19 18:35:46 +01:00
<entry>-43</entry>
</row>
<row>
<entry>ln(<type>double precision</type>)</entry>
<entry><type>double precision</type></entry>
<entry>natural logarithm</entry>
<entry>ln(2.0)</entry>
<entry>0.693147180559945</entry>
</row>
<row>
<entry>log(<type>double precision</type>)</entry>
<entry><type>double precision</type></entry>
<entry>base 10 logarithm</entry>
<entry>log(100.0)</entry>
<entry>2.0</entry>
</row>
<row>
<entry>log(<parameter>base</parameter> <type>numeric</type>, <parameter>x</parameter> <type>numeric</type>)</entry>
<entry><type>numeric</type></entry>
<entry>logarithm to specified base</entry>
<entry>log(2.0, 64.0)</entry>
<entry>6.0</entry>
</row>
<row>
<entry>mod(<parameter>y</parameter>, <parameter>x</parameter>)</entry>
<entry>(same as argument types)</entry>
<entry>remainder (modulo) of the division <parameter>y</parameter>/<parameter>x</parameter></entry>
<entry>mod(9,4)</entry>
<entry>1</entry>
</row>
<row>
<entry>pi()</entry>
<entry><type>double precision</type></entry>
<entry><quote>Pi</quote> constant</entry>
<entry>pi()</entry>
<entry>3.14159265358979</entry>
</row>
<row>
<entry>pow(<type>double precision</type>, <type>double precision</type>)</entry>
<entry><type>double precision</type></entry>
<entry>raise a number to the specified exponent</entry>
<entry>pow(9.0, 3.0)</entry>
<entry>729.0</entry>
</row>
<row>
<entry>radians(<type>double precision</type>)</entry>
<entry><type>double precision</type></entry>
<entry>convert degrees to radians</entry>
<entry>radians(45.0)</entry>
<entry>0.785398163397448</entry>
</row>
<row>
<entry>random()</entry>
<entry><type>double precision</type></entry>
<entry>a pseudo-random value between 0.0 to 1.0</entry>
<entry>random()</entry>
<entry></entry>
</row>
<row>
<entry>round(<type>double precision</type>)</entry>
<entry><type>double precision</type></entry>
<entry>round to nearest integer</entry>
<entry>round(42.4)</entry>
<entry>42</entry>
</row>
<row>
<entry>round(<parameter>value</parameter> <type>numeric</type>, <parameter>scale</parameter> <type>integer</type>)</entry>
<entry><type>numeric</type></entry>
<entry>round to specified number of decimal places</entry>
<entry>round(42.4382, 2)</entry>
<entry>42.44</entry>
</row>
<!--
<row>
<entry>setseed(<replaceable>new-seed</replaceable>)</entry>
<entry>set seed for subsequent random() calls</entry>
<entry>setseed(0.54823)</entry>
<entry></entry>
</row>
-->
<row>
<entry>sqrt(<type>double precision</type>)</entry>
<entry><type>double precision</type></entry>
<entry>square root</entry>
<entry>sqrt(2.0)</entry>
<entry>1.4142135623731</entry>
</row>
<row>
<entry>trunc(<type>double precision</type>)</entry>
<entry><type>double precision</type></entry>
<entry>truncate (toward zero)</entry>
<entry>trunc(42.8)</entry>
<entry>42</entry>
</row>
<row>
<entry>trunc(<parameter>value</parameter> <type>numeric</type>, <parameter>scale</parameter> <type>integer</type>)</entry>
<entry><type>numeric</type></entry>
<entry>truncate to specified number of decimal places</entry>
<entry>round(42.4382, 2)</entry>
<entry>42.43</entry>
</row>
</tbody>
</tgroup>
</table>
<para>
The functions <function>exp</function>, <function>ln</function>,
<function>log</function>, <function>pow</function>,
<function>round</function> (1 argument), <function>sqrt</function>,
and <function>trunc</function> (1 argument) are also available for
the type <type>numeric</type> in place of <type>double
precision</type>. Many of these functions are implemented on top
of the host system's C library and behavior in boundary cases could
therefore vary depending on the operating system.
</para>
<table>
<title>Trigonometric Functions</title>
<tgroup cols="2">
<thead>
<row>
<entry>Function</entry>
<entry>Description</entry>
</row>
</thead>
<tbody>
<row>
<entry>acos(<replaceable>x</replaceable>)</entry>
<entry>inverse cosine</entry>
</row>
<row>
<entry>asin(<replaceable>x</replaceable>)</entry>
<entry>inverse sine</entry>
</row>
<row>
<entry>atan(<replaceable>x</replaceable>)</entry>
<entry>inverse tangent</entry>
</row>
<row>
<entry>atan2(<replaceable>x</replaceable>, <replaceable>y</replaceable>)</entry>
<entry>inverse tangent of <replaceable>y</replaceable>/<replaceable>x</replaceable></entry>
</row>
<row>
<entry>cos(<replaceable>x</replaceable>)</entry>
<entry>cosine</entry>
</row>
<row>
<entry>cot(<replaceable>x</replaceable>)</entry>
<entry>cotangent</entry>
</row>
<row>
<entry>sin(<replaceable>x</replaceable>)</entry>
<entry>sine</entry>
</row>
<row>
<entry>tan(<replaceable>x</replaceable>)</entry>
<entry>tangent</entry>
</row>
</tbody>
</tgroup>
</table>
<para>
All trigonometric functions have arguments and return values of
type <type>double precision</type>.
</para>
</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 all 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 the automatic padding when using the
<type>CHARACTER</type> type. Generally the functions described
here also work on data of non-string types by converting that data
to a string representation first. Some functions also exist
natively for bit string types.
</para>
<para>
<acronym>SQL</acronym> defines some string functions with a special syntax where
certain keywords rather than commas are used to separate the
arguments. Details are in <xref linkend="functions-string-sql">.
These functions are also implemented using the regular syntax for
function invocation. (See <xref linkend="functions-string-other">.)
</para>
<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> <parameter>string</parameter> <literal>||</literal> <parameter>string</parameter> </entry>
<entry> <type>text</type> </entry>
<entry>string concatenation</entry>
<entry>'Postgre' || 'SQL'</entry>
<entry>PostgreSQL</entry>
</row>
<row>
<entry>char_length(<parameter>string</parameter>) or character_length(<parameter>string</parameter>)</entry>
<entry><type>integer</type></entry>
<entry>length of string</entry>
<entry>char_length('jose')</entry>
<entry>4</entry>
</row>
<row>
<entry>lower(<parameter>string</parameter>)</entry>
<entry><type>text</type></entry>
<entry>Convert string to lower case.</entry>
<entry>lower('TOM')</entry>
<entry>tom</entry>
</row>
<row>
<entry>octet_length(<parameter>string</parameter>)</entry>
<entry><type>integer</type></entry>
<entry>number of bytes in string</entry>
<entry>octet_length('jose')</entry>
<entry>4</entry>
</row>
<row>
<entry>position(<parameter>substring</parameter> in <parameter>string</parameter>)</entry>
<entry><type>integer</type></entry>
<entry>location of specified substring</entry>
<entry>position('om' in 'Thomas')</entry>
<entry>3</entry>
</row>
<row>
<entry>substring(<parameter>string</parameter> <optional>from <type>integer</type></optional> <optional>for <type>integer</type></optional>)</entry>
<entry><type>text</type></entry>
<entry>extract substring</entry>
<entry>substring('Thomas' from 2 for 3)</entry>
<entry>oma</entry>
</row>
<row>
<entry>
trim(<optional>leading | trailing | both</optional>
<optional><parameter>characters</parameter></optional> from
<parameter>string</parameter>)
</entry>
<entry><type>text</type></entry>
<entry>
Removes the longest string containing only the
<parameter>characters</parameter> (a space by default) from the
beginning/end/both ends of the <parameter>string</parameter>.
</entry>
<entry>trim(both 'x' from 'xTomx')</entry>
<entry>Tom</entry>
</row>
<row>
<entry>upper(<parameter>string</parameter>)</entry>
<entry><type>text</type></entry>
<entry>Convert string to upper case.</entry>
<entry>upper('tom')</entry>
<entry>TOM</entry>
</row>
</tbody>
</tgroup>
</table>
1999-06-14 09:36:12 +02:00
<para>
Additional string manipulation functions are available and are
listed below. Some of them are used internally to implement the
<acronym>SQL</acronym> string functions listed above.
1999-06-14 09:36:12 +02:00
</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>ascii(<type>text</type>)</entry>
<entry>integer</entry>
<entry>Returns the <acronym>ASCII</acronym> code of the first character of the argument.</entry>
<entry>ascii('x')</entry>
<entry>120</entry>
</row>
<row>
<entry>btrim(<parameter>string</parameter> <type>text</type>, <parameter>trim</parameter> <type>text</type>)</entry>
<entry><type>text</type></entry>
<entry>
Remove (trim) the longest string consisting only of characters
in <parameter>trim</parameter> from the start and end of
<parameter>string</parameter>.
</entry>
<entry>btrim('xyxtrimyyx','xy')</entry>
<entry>trim</entry>
</row>
<row>
<entry>chr(<type>integer</type>)</entry>
<entry><type>text</type></entry>
<entry>Returns the character with the given <acronym>ASCII</acronym> code.</entry>
<entry>chr(65)</entry>
<entry>A</entry>
</row>
<row>
<entry>initcap(<type>text</type>)</entry>
<entry><type>text</type></entry>
<entry>Converts first letter of each word (whitespace separated) to upper case.</entry>
<entry>initcap('hello thomas')</entry>
<entry>Hello Thomas</entry>
</row>
<row>
<entry>
lpad(<parameter>string</parameter> <type>text</type>,
<parameter>length</parameter> <type>integer</type>
<optional>, <parameter>fill</parameter> <type>text</type></optional>)
</entry>
<entry>text</entry>
<entry>
Fills 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>lpad('hi', 5, 'xy')</entry>
<entry>xyxhi</entry>
</row>
<row>
<entry>ltrim(<parameter>string</parameter> <type>text</type>, <parameter>trim</parameter> <type>text</type>)</entry>
<entry><type>text</type></entry>
<entry>
Removes the longest string containing only characters from
<parameter>trim</parameter> from the start of the string.
</entry>
<entry>ltrim('zzzytrim','xyz')</entry>
<entry>trim</entry>
</row>
<row>
<entry>repeat(<type>text</type>, <type>integer</type>)</entry>
<entry><type>text</type></entry>
<entry>Repeat text a number of times.</entry>
<entry>repeat('Pg', 4)</entry>
<entry>PgPgPgPg</entry>
</row>
<row>
<entry>
rpad(<parameter>string</parameter> <type>text</type>,
<parameter>length</parameter> <type>integer</type>
<optional>, <parameter>fill</parameter> <type>text</type></optional>)
</entry>
<entry><type>text</type></entry>
<entry>
Fills 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>rpad('hi', 5, 'xy')</entry>
<entry>hixyx</entry>
</row>
<row>
<entry>rtrim(<parameter>string</parameter> text, <parameter>trim</parameter> text)</entry>
<entry><type>text</type></entry>
<entry>
Removes the longest string containing only characters from
<parameter>trim</parameter> from the end of the string.
</entry>
<entry>rtrim('trimxxxx','x')</entry>
<entry>trim</entry>
</row>
<row>
<entry>strpos(<parameter>string</parameter>, <parameter>substring</parameter>)</entry>
<entry><type>text</type></entry>
<entry>
Locates specified substring. (same as
<literal>position(<parameter>substring</parameter> in
<parameter>string</parameter>)</literal>, but note the reversed
argument order)
</entry>
<entry>strpos('high','ig')</entry>
<entry>2</entry>
</row>
<row>
<entry>substr(<parameter>string</parameter>, <parameter>from</parameter> <optional>, <parameter>count</parameter></optional>)</entry>
<entry><type>text</type></entry>
<entry>
Extracts specified substring. (same as <literal>substring(<parameter>string</parameter> from <parameter>from</parameter> for <parameter>count</parameter>)</literal>)
</entry>
<entry>substr('alphabet', 3, 2)</entry>
<entry>ph</entry>
</row>
<row>
<entry>to_ascii(<type>text</type> <optional>, <parameter>encoding</parameter></optional>)</entry>
<entry><type>text</type></entry>
<entry>Converts text from multibyte encoding to <acronym>ASCII</acronym>.</entry>
<entry>to_ascii('Karel')</entry>
<entry>Karel</entry>
</row>
<row>
<entry>
translate(<parameter>string</parameter> <type>text</type>,
<parameter>from</parameter> <type>text</type>,
<parameter>to</parameter> <type>text</type>)
</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.
</entry>
<entry>translate('12345', '14', 'ax')</entry>
<entry>a23x5</entry>
</row>
</tbody>
</tgroup>
</table>
<para>
The <function>to_ascii</function> function supports conversion from
LATIN1, LATIN2, WIN1250 (CP1250) only.
</para>
</sect1>
<sect1 id="functions-matching">
<title>Pattern Matching</title>
<para>
There are two separate approaches to pattern matching provided by
<productname>Postgres</productname>: the <acronym>SQL</acronym>
<function>LIKE</function> operator and
<acronym>POSIX</acronym>-style regular expressions.
</para>
<tip>
<para>
If you have pattern matching needs that go beyond this, or want to
make pattern-driven substitutions or translations, consider
writing a user-defined function in Perl or Tcl.
</para>
</tip>
<sect2 id="functions-like">
<title>Pattern Matching with <function>LIKE</function></title>
<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>
Every <replaceable>pattern</replaceable> defines a set of strings.
The <function>LIKE</function> expression returns true if the
<replaceable>string</replaceable> is contained in the set of
strings represented by <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 underscore, 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 string
of zero or more characters.
</para>
<informalexample>
<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>
</informalexample>
1999-06-14 09:36:12 +02:00
<para>
<function>LIKE</function> pattern matches always cover the entire
string. To match a pattern anywhere within a string, the
pattern must therefore start and end with a percent sign.
1999-06-14 09:36:12 +02:00
</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 may be selected by
using the <literal>ESCAPE</literal> clause. To match the escape
character itself, write two escape characters.
</para>
<para>
Note that the backslash already has a special meaning in string
literals, so to write a pattern constant that contains a backslash
you must write two backslashes in the query. You can avoid this by
selecting a different escape character with <literal>ESCAPE</literal>.
</para>
<para>
The keyword <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>Postgres</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>. All of these are also
<productname>Postgres</productname>-specific.
</para>
</sect2>
<sect2 id="functions-regexp">
<title><acronym>POSIX</acronym> Regular Expressions</title>
<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>'thomas' ~ '.*thomas.*'</ENTRY>
</ROW>
<ROW>
<ENTRY> <literal>~*</literal> </ENTRY>
<ENTRY>Matches regular expression, case insensitive</ENTRY>
<ENTRY>'thomas' ~* '.*Thomas.*'</ENTRY>
</ROW>
<ROW>
<ENTRY> <literal>!~</literal> </ENTRY>
<ENTRY>Does not match regular expression, case sensitive</ENTRY>
<ENTRY>'thomas' !~ '.*Thomas.*'</ENTRY>
</ROW>
<ROW>
<ENTRY> <literal>!~*</literal> </ENTRY>
<ENTRY>Does not match regular expression, case insensitive</ENTRY>
<ENTRY>'thomas' !~* '.*vadim.*'</ENTRY>
</ROW>
</tbody>
</tgroup>
</table>
<para>
<acronym>POSIX</acronym> regular expressions provide a more powerful means for
pattern matching than the <function>LIKE</function> function.
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>
<!-- derived from the re_format.7 man page -->
1999-06-14 09:36:12 +02:00
<para>
Regular expressions (<quote>RE</quote>s), as defined in <acronym>POSIX</acronym>
1003.2, come in two forms: modern REs (roughly those of
<command>egrep</command>; 1003.2 calls these
<quote>extended</quote> REs) and obsolete REs (roughly those of
<command>ed</command>; 1003.2 <quote>basic</quote> REs).
<productname>Postgres</productname> implements the modern form.
1999-06-14 09:36:12 +02:00
</para>
1999-06-14 09:36:12 +02:00
<para>
A (modern) RE is one or more non-empty
<firstterm>branches</firstterm>, separated by
<literal>|</literal>. It matches anything that matches one of the
branches.
1999-06-14 09:36:12 +02:00
</para>
<para>
A branch is one or more <firstterm>pieces</firstterm>,
concatenated. It matches a match for the first, followed by a
match for the second, etc.
</para>
<para>
A piece is an <firstterm>atom</firstterm> possibly followed by a
single <literal>*</literal>, <literal>+</literal>,
<literal>?</literal>, or <firstterm>bound</firstterm>. An atom
followed by <literal>*</literal> matches a sequence of 0 or more
matches of the atom. An atom followed by <literal>+</literal>
matches a sequence of 1 or more matches of the atom. An atom
followed by <literal>?</literal> matches a sequence of 0 or 1
matches of the atom.
</para>
<para>
A <firstterm>bound</firstterm> is <literal>{</literal> followed by
an unsigned decimal integer, possibly followed by
<literal>,</literal> possibly followed by another unsigned decimal
integer, always followed by <literal>}</literal>. The integers
must lie between 0 and <symbol>RE_DUP_MAX</symbol> (255)
inclusive, and if there are two of them, the first may not exceed
the second. An atom followed by a bound containing one integer
<replaceable>i</replaceable> and no comma matches a sequence of
exactly <replaceable>i</replaceable> matches of the atom. An atom
followed by a bound containing one integer
<replaceable>i</replaceable> and a comma matches a sequence of
<replaceable>i</replaceable> or more matches of the atom. An atom
followed by a bound containing two integers
<replaceable>i</replaceable> and <replaceable>j</replaceable>
matches a sequence of <replaceable>i</replaceable> through
<replaceable>j</replaceable> (inclusive) matches of the atom.
</para>
<note>
<para>
A repetition operator (<literal>?</literal>,
<literal>*</literal>, <literal>+</literal>, or bounds) cannot
follow another repetition operator. A repetition operator cannot
begin an expression or subexpression or follow
<literal>^</literal> or <literal>|</literal>.
</para>
</note>
<para>
An <firstterm>atom</firstterm> is a regular expression enclosed in
<literal>()</literal> (matching a match for the regular
expression), an empty set of <literal>()</literal> (matching the
null string), a <firstterm>bracket expression</firstterm> (see
below), <literal>.</literal> (matching any single character),
<literal>^</literal> (matching the null string at the beginning of
a line), <literal>$</literal> (matching the null string at the end
of a line), a <literal>\</literal> followed by one of the
characters <literal>^.[$()|*+?{\</literal> (matching that
character taken as an ordinary character), a <literal>\</literal>
followed by any other character (matching that character taken as
an ordinary character, as if the <literal>\</literal> had not been
present), or a single character with no other significance
(matching that character). A <literal>{</literal> followed by a
character other than a digit is an ordinary character, not the
beginning of a bound. It is illegal to end an RE with
<literal>\</literal>.
</para>
<para>
Note that the backslash (<literal>\</literal>) already has a special
meaning in string
literals, so to write a pattern constant that contains a backslash
you must write two backslashes in the query.
</para>
1999-06-14 09:36:12 +02:00
<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
(but see below) not from the rest of the list. If two characters
in the list are separated by <literal>-</literal>, this is
shorthand for the full range of characters between those two
(inclusive) in the collating sequence,
e.g. <literal>[0-9]</literal> in <acronym>ASCII</acronym> matches
any decimal digit. It is illegal for two ranges to share an
endpoint, e.g. <literal>a-c-e</literal>. Ranges are very
collating-sequence-dependent, and portable programs should avoid
relying on them.
1999-06-14 09:36:12 +02:00
</para>
1999-06-14 09:36:12 +02:00
<para>
To include a literal <literal>]</literal> in the list, make it the
first character (following a possible <literal>^</literal>). 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 and
some combinations using <literal>[</literal> (see next
paragraphs), all other special characters, including
<literal>\</literal>, lose their special significance within a
bracket expression.
</para>
<para>
Within a bracket expression, a collating element (a character, a
multi-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
a single element of the bracket expression's list. A bracket
expression containing a multi-character collating element can thus
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>
<para>
Within a bracket expression, a collating element enclosed in
<literal>[=</literal> and <literal>=]</literal> is an equivalence
class, standing for the sequences of characters of all collating
elements equivalent to that one, including itself. (If there are
no other equivalent collating elements, the treatment is as if the
enclosing delimiters were <literal>[.</literal> and
<literal>.]</literal>.) For example, if <literal>o</literal> and
<literal>^</literal> are the members of an equivalence class, then
<literal>[[=o=]]</literal>, <literal>[[=^=]]</literal>, and
<literal>[o^]</literal> are all synonymous. An equivalence class
may not be an endpoint of a range.
</para>
<para>
Within a bracket expression, the name of a character class
enclosed in <literal>[:</literal> and <literal>:]</literal> stands
for the list of all characters belonging to that class. Standard
character class names are: <literal>alnum</literal>,
<literal>alpha</literal>, <literal>blank</literal>,
<literal>cntrl</literal>, <literal>digit</literal>,
<literal>graph</literal>, <literal>lower</literal>,
<literal>print</literal>, <literal>punct</literal>,
<literal>space</literal>, <literal>upper</literal>,
<literal>xdigit</literal>. These stand for the character classes
defined in
<citerefentry><refentrytitle>ctype</refentrytitle><manvolnum>3</manvolnum></citerefentry>.
A locale may provide others. A character class may not be used as
an endpoint of a range.
</para>
<para>
There are two special cases of bracket expressions: the bracket
expressions <literal>[[:<:]]</literal> and
<literal>[[:>:]]</literal> match the null string at the beginning
and end of a word respectively. A word is defined as a sequence
of word characters which is neither preceded nor followed by word
characters. A word character is an alnum character (as defined by
<citerefentry><refentrytitle>ctype</refentrytitle><manvolnum>3</manvolnum></citerefentry>)
or an underscore. This is an extension, compatible with but not
specified by POSIX 1003.2, and should be used with caution in
software intended to be portable to other systems.
</para>
<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, it matches the longest. Subexpressions also match the
longest possible substrings, subject to the constraint that the
whole match be as long as possible, with subexpressions starting
earlier in the RE taking priority over ones starting later. Note
that higher-level subexpressions thus take priority over their
lower-level component subexpressions.
</para>
<para>
Match lengths are measured in characters, not collating
elements. A null string is considered longer than no match at
all. For example, <literal>bb*</literal> matches the three middle
characters of <literal>abbbc</literal>,
<literal>(wee|week)(knights|nights)</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 the null 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, so that (e.g.)
<literal>[x]</literal> becomes <literal>[xX]</literal> and
<literal>[^x]</literal> becomes <literal>[^xX]</literal>.
</para>
<para>
There is no particular limit on the length of REs, except insofar
as memory is limited. Memory usage is approximately linear in RE
size, and largely insensitive to RE complexity, except for bounded
repetitions. Bounded repetitions are implemented by macro
expansion, which is costly in time and space if counts are large
or bounded repetitions are nested. An RE like, say,
<literal>((((a{1,100}){1,100}){1,100}){1,100}){1,100}</literal>
will (eventually) run almost any existing machine out of swap
space.<footnote><para>This was written in 1994, mind you. The
numbers have probably changed, but the problem
persists.</para></footnote>
1999-06-14 09:36:12 +02:00
</para>
<!-- end re_format.7 man page -->
</sect2>
</sect1>
<sect1 id="functions-formatting">
<title>Formatting Functions</title>
<note>
<title>Author</title>
<para>
Written by Karel Zak (<email>zakkr@zf.jcu.cz</email>) on 2000-01-24
</para>
</note>
<para>
The <productname>Postgres</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.
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 format.
</para>
<para>
<table tocentry="1">
<title>Formatting Functions</title>
<tgroup cols="4">
<thead>
<row>
<entry>Function</entry>
<entry>Returns</entry>
<entry>Description</entry>
<entry>Example</entry>
</row>
</thead>
<tbody>
<row>
<entry>to_char(timestamp, text)</entry>
<entry>text</entry>
<entry>convert timestamp to string</entry>
<entry>to_char(timestamp 'now','HH12:MI:SS')</entry>
</row>
<row>
<entry>to_char(int, text)</entry>
<entry>text</entry>
<entry>convert int4/int8 to string</entry>
<entry>to_char(125, '999')</entry>
</row>
<row>
<entry>to_char(double precision, text)</entry>
<entry>text</entry>
<entry>convert real/double precision to string</entry>
<entry>to_char(125.8, '999D9')</entry>
</row>
<row>
<entry>to_char(numeric, text)</entry>
<entry>text</entry>
<entry>convert numeric to string</entry>
<entry>to_char(numeric '-125.8', '999D99S')</entry>
</row>
<row>
<entry>to_date(text, text)</entry>
<entry>date</entry>
<entry>convert string to date</entry>
<entry>to_date('05 Dec 2000', 'DD Mon YYYY')</entry>
</row>
<row>
<entry>to_timestamp(text, text)</entry>
<entry>date</entry>
<entry>convert string to timestamp</entry>
<entry>to_timestamp('05 Dec 2000', 'DD Mon YYYY')</entry>
</row>
<row>
<entry>to_number(text, text)</entry>
<entry>numeric</entry>
<entry>convert string to numeric</entry>
<entry>to_number('12,454.8-', '99G999D9S')</entry>
</row>
</tbody>
</tgroup>
</table>
</para>
<para>
<table tocentry="1">
<title>Templates for date/time conversions</title>
<tgroup cols="2">
<thead>
<row>
<entry>Template</entry>
<entry>Description</entry>
</row>
</thead>
<tbody>
<row>
<entry>HH</entry>
<entry>hour of day (01-12)</entry>
</row>
<row>
<entry>HH12</entry>
<entry>hour of day (01-12)</entry>
</row>
<row>
<entry>HH24</entry>
<entry>hour of day (00-23)</entry>
</row>
<row>
<entry>MI</entry>
<entry>minute (00-59)</entry>
</row>
<row>
<entry>SS</entry>
<entry>second (00-59)</entry>
</row>
<row>
<entry>SSSS</entry>
<entry>seconds past midnight (0-86399)</entry>
</row>
2000-04-07 21:17:51 +02:00
<row>
<entry>AM or A.M. or PM or P.M.</entry>
<entry>meridian indicator (upper case)</entry>
</row>
<row>
<entry>am or a.m. or pm or p.m.</entry>
<entry>meridian indicator (lower case)</entry>
</row>
<row>
<entry>Y,YYY</entry>
<entry>year (4 and more digits) with comma</entry>
</row>
<row>
<entry>YYYY</entry>
<entry>year (4 and more digits)</entry>
</row>
<row>
<entry>YYY</entry>
<entry>last 3 digits of year</entry>
</row>
<row>
<entry>YY</entry>
<entry>last 2 digits of year</entry>
</row>
<row>
<entry>Y</entry>
<entry>last digit of year</entry>
</row>
2000-04-07 21:17:51 +02:00
<row>
<entry>BC or B.C. or AD or A.D.</entry>
<entry>year indicator (upper case)</entry>
</row>
<row>
<entry>bc or b.c. or ad or a.d.</entry>
<entry>year indicator (lower case)</entry>
</row>
<row>
<entry>MONTH</entry>
<entry>full upper case month name (9 chars)</entry>
</row>
<row>
<entry>Month</entry>
<entry>full mixed case month name (9 chars)</entry>
</row>
<row>
<entry>month</entry>
<entry>full lower case month name (9 chars)</entry>
</row>
<row>
<entry>MON</entry>
<entry>upper case abbreviated month name (3 chars)</entry>
</row>
<row>
<entry>Mon</entry>
<entry>abbreviated mixed case month name (3 chars)</entry>
</row>
<row>
<entry>mon</entry>
<entry>abbreviated lower case month name (3 chars)</entry>
</row>
<row>
<entry>MM</entry>
<entry>month (01-12)</entry>
</row>
<row>
<entry>DAY</entry>
<entry>full upper case day name (9 chars)</entry>
</row>
<row>
<entry>Day</entry>
<entry>full mixed case day name (9 chars)</entry>
</row>
<row>
<entry>day</entry>
<entry>full lower case day name (9 chars)</entry>
</row>
<row>
<entry>DY</entry>
<entry>abbreviated upper case day name (3 chars)</entry>
</row>
<row>
<entry>Dy</entry>
<entry>abbreviated mixed case day name (3 chars)</entry>
</row>
<row>
<entry>dy</entry>
<entry>abbreviated lower case day name (3 chars)</entry>
</row>
<row>
<entry>DDD</entry>
<entry>day of year (001-366)</entry>
</row>
<row>
<entry>DD</entry>
<entry>day of month (01-31)</entry>
</row>
<row>
<entry>D</entry>
<entry>day of week (1-7; SUN=1)</entry>
</row>
<row>
<entry>W</entry>
<entry>week of month (1-5) where first week start on the first day of the month</entry>
</row>
<row>
<entry>WW</entry>
<entry>week number of year (1-53) where first week start on the first day of the year</entry>
</row>
<row>
<entry>IW</entry>
<entry>ISO week number of year (The first Thursday of the new year is in week 1.)</entry>
</row>
<row>
<entry>CC</entry>
<entry>century (2 digits)</entry>
</row>
<row>
<entry>J</entry>
<entry>Julian Day (days since January 1, 4712 BC)</entry>
</row>
<row>
<entry>Q</entry>
<entry>quarter</entry>
</row>
<row>
<entry>RM</entry>
<entry>month in Roman Numerals (I-XII; I=January) - upper case</entry>
2000-04-07 21:17:51 +02:00
</row>
<row>
<entry>rm</entry>
<entry>month in Roman Numerals (I-XII; I=January) - lower case</entry>
</row>
<row>
<entry>TZ</entry>
<entry>timezone string - upper case</entry>
</row>
<row>
<entry>tz</entry>
<entry>timezone string - lower case</entry>
</row>
</tbody>
</tgroup>
</table>
</para>
<para>
All templates allow the use of prefix and suffix modifiers. Modifiers are
always valid for use in templates. The prefix
<quote><literal>FX</literal></quote> is a global modifier only.
</para>
<para>
<table tocentry="1">
<title>Suffixes for templates for date/time to_char()</title>
<tgroup cols="3">
<thead>
<row>
<entry>Suffix</entry>
<entry>Description</entry>
<entry>Example</entry>
</row>
</thead>
<tbody>
<row>
<entry>FM</entry>
<entry>fill mode prefix</entry>
<entry>FMMonth</entry>
</row>
<row>
<entry>TH</entry>
<entry>upper ordinal number suffix</entry>
<entry>DDTH</entry>
</row>
<row>
<entry>th</entry>
<entry>lower ordinal number suffix</entry>
<entry>DDTH</entry>
</row>
<row>
<entry>FX</entry>
<entry>FiXed format global option (see below)</entry>
<entry>FX Month DD Day</entry>
</row>
<row>
<entry>SP</entry>
<entry>spell mode (not yet implemented)</entry>
<entry>DDSP</entry>
</row>
</tbody>
</tgroup>
</table>
</para>
<para>
Usage notes:
<itemizedlist>
<listitem>
<para>
<function>to_timestamp</function> and <function>to_date</function>
skip multiple blank space in converted string if the <literal>FX</literal> option
is not used. <literal>FX</literal> must be specified as the first item
in the template; for example
<literal>to_timestamp('2000 JUN','YYYY MON')</literal> is right, but
<literal>to_timestamp('2000 JUN','FXYYYY MON')</literal> returns error,
because to_timestamp() expects one blank space only.
</para>
</listitem>
<listitem>
<para>
If a backslash (<quote><literal>\</literal></quote>) is desired
in a string constant, a double backslash
(<quote><literal>\\</literal></quote>) must be entered; for
example <literal>'\\HH\\MI\\SS'</literal>. This is true for
any string constant in <productname>Postgres</productname>.
</para>
</listitem>
<listitem>
<para>
Ordinary text is allowed in <function>to_char</function>
templates but any string between double quotes is guaranteed
that it will not be interpreted as a template keyword and it is
also processed faster. (Example: <literal>'"Hello Year:
"YYYY'</literal>).
</para>
</listitem>
<listitem>
<para>
A double quote (<quote><literal>"</literal></quote>) between
quotation marks is skipped and is not parsed. If you want to
have a double quote in the output you must precede it with a
double backslash, for example <literal>'\\"YYYY
Month\\"'</literal>. <!-- " font-lock sanity :-) -->
</para>
</listitem>
<listitem>
<para>
<literal>YYYY</literal> conversion from string to timestamp or
date is restricted if you use a year with more than 4 digits. You must
2000-11-25 14:20:05 +01:00
use some non-digit character or template after <literal>YYYY</literal>,
otherwise the year is always interpreted as 4 digits. For example
2000-11-25 14:20:05 +01:00
(with year 20000):
<literal>to_date('200001131', 'YYYYMMDD')</literal> will be
interpreted as a 4-digit year; better is to use a non-digit
2000-11-25 14:20:05 +01:00
separator after the year, like
<literal>to_date('20000-1131', 'YYYY-MMDD')</literal> or
<literal>to_date('20000Nov31', 'YYYYMonDD')</literal>.
</para>
</listitem>
</itemizedlist>
</para>
<para>
<table tocentry="1">
<title>Templates for to_char(<replaceable>numeric</replaceable>)</title>
<tgroup cols="2">
<thead>
<row>
<entry>Template</entry>
<entry>Description</entry>
</row>
</thead>
<tbody>
<row>
<entry>9</entry>
<entry>value with the specified number of digits</entry>
</row>
<row>
<entry>0</entry>
<entry>value with leading zeros</entry>
</row>
<row>
<entry>. (period)</entry>
<entry>decimal point</entry>
</row>
<row>
<entry>, (comma)</entry>
<entry>group (thousand) separator</entry>
</row>
<row>
<entry>PR</entry>
<entry>negative value in angle brackets</entry>
</row>
<row>
<entry>S</entry>
<entry>negative value with minus sign (uses locale)</entry>
</row>
<row>
<entry>L</entry>
<entry>currency symbol (uses locale)</entry>
</row>
<row>
<entry>D</entry>
<entry>decimal point (uses locale)</entry>
</row>
<row>
<entry>G</entry>
<entry>group separator (uses locale)</entry>
</row>
<row>
<entry>MI</entry>
<entry>minus sign in specified position (if number < 0)</entry>
</row>
<row>
<entry>PL</entry>
<entry>plus sign in specified position (if number > 0)</entry>
</row>
<row>
<entry>SG</entry>
<entry>plus/minus sign in specified position</entry>
</row>
<row>
<entry>RN</entry>
<entry>roman numeral (input between 1 and 3999)</entry>
</row>
<row>
<entry>TH or th</entry>
<entry>convert to ordinal number</entry>
</row>
<row>
<entry>V</entry>
<entry>shift <replaceable>n</replaceable> digits (see
notes)</entry>
</row>
<row>
<entry>EEEE</entry>
<entry>scientific numbers (not supported yet)</entry>
</row>
</tbody>
</tgroup>
</table>
</para>
<para>
Usage notes:
<itemizedlist>
<listitem>
<para>
A sign formatted using 'SG', 'PL' or 'MI' is not an anchor in
the number; for example,
to_char(-12, 'S9999') produces <literal>' -12'</literal>,
but to_char(-12, 'MI9999') produces <literal>'- 12'</literal>.
The Oracle implementation does not allow the use of
<literal>MI</literal> ahead of <literal>9</literal>, but rather
requires that <literal>9</literal> precede
<literal>MI</literal>.
</para>
</listitem>
<listitem>
<para>
<literal>PL</literal>, <literal>SG</literal>, and
<literal>TH</literal> are <productname>Postgres</productname>
extensions.
</para>
</listitem>
<listitem>
<para>
<literal>9</literal> specifies a value with the same number of
digits as there are <literal>9</literal>s. If a digit is
not available use blank space.
</para>
</listitem>
<listitem>
<para>
<literal>TH</literal> does not convert values less than zero
and does not convert decimal numbers. <literal>TH</literal> is
a <productname>Postgres</productname> extension.
</para>
</listitem>
<listitem>
<para>
<literal>V</literal> effectively
multiplies the input values by
<literal>10^<replaceable>n</replaceable></literal>, where
<replaceable>n</replaceable> is the number of digits following
<literal>V</literal>.
<function>to_char</function> does not support the use of
<literal>V</literal> combined with a decimal point.
(E.g., <literal>99.9V99</literal> is not allowed.)
</para>
</listitem>
</itemizedlist>
</para>
<para>
<table tocentry="1">
<title><function>to_char</function> Examples</title>
<tgroup cols="2">
<thead>
<row>
<entry>Input</entry>
<entry>Output</entry>
</row>
</thead>
<tbody>
<row>
<entry>to_char(now(),'Day, HH12:MI:SS')</entry>
<entry><literal>'Tuesday , 05:39:18'</literal></entry>
</row>
<row>
<entry>to_char(now(),'FMDay, HH12:MI:SS')</entry>
<entry><literal>'Tuesday, 05:39:18'</literal></entry>
</row>
<row>
<entry>to_char(-0.1,'99.99')</entry>
<entry><literal>' -.10'</literal></entry>
</row>
<row>
<entry>to_char(-0.1,'FM9.99')</entry>
<entry><literal>'-.1'</literal></entry>
</row>
<row>
<entry>to_char(0.1,'0.9')</entry>
<entry><literal>' 0.1'</literal></entry>
</row>
<row>
<entry>to_char(12,'9990999.9')</entry>
<entry><literal>' 0012.0'</literal></entry>
</row>
<row>
<entry>to_char(12,'FM9990999.9')</entry>
<entry><literal>'0012'</literal></entry>
</row>
<row>
<entry>to_char(485,'999')</entry>
<entry><literal>' 485'</literal></entry>
</row>
<row>
<entry>to_char(-485,'999')</entry>
<entry><literal>'-485'</literal></entry>
</row>
<row>
<entry>to_char(485,'9 9 9')</entry>
<entry><literal>' 4 8 5'</literal></entry>
</row>
<row>
<entry>to_char(1485,'9,999')</entry>
<entry><literal>' 1,485'</literal></entry>
</row>
<row>
<entry>to_char(1485,'9G999')</entry>
<entry><literal>' 1 485'</literal></entry>
</row>
<row>
<entry>to_char(148.5,'999.999')</entry>
<entry><literal>' 148.500'</literal></entry>
</row>
<row>
<entry>to_char(148.5,'999D999')</entry>
<entry><literal>' 148,500'</literal></entry>
</row>
<row>
<entry>to_char(3148.5,'9G999D999')</entry>
<entry><literal>' 3 148,500'</literal></entry>
</row>
<row>
<entry>to_char(-485,'999S')</entry>
<entry><literal>'485-'</literal></entry>
</row>
<row>
<entry>to_char(-485,'999MI')</entry>
<entry><literal>'485-'</literal></entry>
</row>
<row>
<entry>to_char(485,'999MI')</entry>
<entry><literal>'485'</literal></entry>
</row>
<row>
<entry>to_char(485,'PL999')</entry>
<entry><literal>'+485'</literal></entry>
</row>
<row>
<entry>to_char(485,'SG999')</entry>
<entry><literal>'+485'</literal></entry>
</row>
<row>
<entry>to_char(-485,'SG999')</entry>
<entry><literal>'-485'</literal></entry>
</row>
<row>
<entry>to_char(-485,'9SG99')</entry>
<entry><literal>'4-85'</literal></entry>
</row>
<row>
<entry>to_char(-485,'999PR')</entry>
<entry><literal>'&lt;485&gt;'</literal></entry>
</row>
<row>
<entry>to_char(485,'L999')</entry>
<entry><literal>'DM 485</literal></entry>
</row>
<row>
<entry>to_char(485,'RN')</entry>
<entry><literal>' CDLXXXV'</literal></entry>
</row>
<row>
<entry>to_char(485,'FMRN')</entry>
<entry><literal>'CDLXXXV'</literal></entry>
</row>
<row>
<entry>to_char(5.2,'FMRN')</entry>
<entry><literal>V</literal></entry>
</row>
<row>
<entry>to_char(482,'999th')</entry>
<entry><literal>' 482nd'</literal></entry>
</row>
<row>
<entry>to_char(485, '"Good number:"999')</entry>
<entry><literal>'Good number: 485'</literal></entry>
</row>
<row>
<entry>to_char(485.8,'"Pre-decimal:"999" Post-decimal:" .999')</entry>
<entry><literal>'Pre-decimal: 485 Post-decimal: .800'</literal></entry>
</row>
<row>
<entry>to_char(12,'99V999')</entry>
<entry><literal>' 12000'</literal></entry>
</row>
<row>
<entry>to_char(12.4,'99V999')</entry>
<entry><literal>' 12400'</literal></entry>
</row>
<row>
<entry>to_char(12.45, '99V9')</entry>
<entry><literal>' 125'</literal></entry>
</row>
</tbody>
</tgroup>
</table>
</para>
</sect1>
<sect1 id="functions-datetime">
<title>Date/Time Functions</title>
<para>
<xref linkend="functions-datetime-table"> shows the available
functions for date/time value processing. The basic arithmetic
operators (<literal>+</literal>, <literal>*</literal>, etc.) are
also available. For formatting functions, refer to <xref
linkend="functions-formatting">. You should be familiar with the
background information on date/time data types (see <xref
linkend="datatype-datetime">).
</para>
<table id="functions-datetime-table">
<title>Date/Time Functions</title>
<tgroup cols="4">
<thead>
<row>
<entry>Name</entry>
<entry>Return Type</entry>
<entry>Description</entry>
<entry>Example</entry>
<entry>Result</entry>
</row>
</thead>
<tbody>
<![IGNORE[
<!--
These two functions don't seem to do what it says here, or anything
reasonable at all for that matter.
-->
<row>
<entry>age(timestamp)</entry>
<entry>interval</entry>
<entry>Subtract argument from current date, preserve years and months and days</entry>
<entry>age(timestamp '1957-06-13')</entry>
<entry>43 years 8 mons 3 days</entry>
</row>
<row>
<entry>age(timestamp, timestamp)</entry>
<entry>interval</entry>
<entry>preserve months and years</entry>
<entry>age('now', timestamp '1957-06-13')</entry>
<entry></entry>
</row>
]]>
<row>
<entry>current_date</entry>
<entry>date</entry>
<entry>
returns current date; see also <link
linkend="functions-datetime-current">below</link>
</entry>
<entry></entry>
<entry></entry>
</row>
<row>
<entry>current_time</entry>
<entry>time</entry>
<entry>
returns current time (of day); see also <link
linkend="functions-datetime-current">below</link>
</entry>
<entry></entry>
<entry></entry>
</row>
<row>
<entry>current_timestamp</entry>
<entry>timestamp</entry>
<entry>
returns current date and time; see also <link
linkend="functions-datetime-current">below</link>
</entry>
<entry></entry>
<entry></entry>
</row>
<row>
<entry>date_part(text, timestamp)</entry>
<entry>double precision</entry>
<entry>
extract subfield from date/time value (equivalent to
<function>extract</function>); see also <link
linkend="functions-datetime-datepart">below</link>
</entry>
<entry>date_part('hour', timestamp '2001-02-16 20:38:40')</entry>
<entry>20</entry>
</row>
<row>
<entry>date_part(text, interval)</entry>
<entry>double precision</entry>
<entry>
extract subfield from interval value (equivalent to
<function>extract</function>); see also <link
linkend="functions-datetime-datepart">below</link>
</entry>
<entry>date_part('month', interval '2 years 3 months')</entry>
<entry>3</entry>
</row>
<row>
<entry>date_trunc(text, timestamp)</entry>
<entry>timestamp</entry>
<entry>
truncate date to specified precision; see also <link
linkend="functions-datetime-trunc">below</link>
</entry>
<entry>date_trunc('hour', timestamp '2001-02-16 20:38:40')</entry>
<entry>2001-02-16 20:00:00+00</entry>
</row>
<row>
<entry>extract(identifier from timestamp)</entry>
<entry>double precision</entry>
<entry>
extract subfield from date/time value; see also <link
linkend="functions-datetime-extract">below</link>
</entry>
<entry>extract(hour from timestamp '2001-02-16 20:38:40')</entry>
<entry>20</entry>
</row>
<row>
<entry>extract(identifier from interval)</entry>
<entry>double precision</entry>
<entry>
extract subfield from interval value; see also <link
linkend="functions-datetime-extract">below</link>
</entry>
<entry>extract(month from interval '2 years 3 months')</entry>
<entry>3</entry>
</row>
<row>
<entry>isfinite(timestamp)</entry>
<entry>boolean</entry>
<entry>Returns true if the time stamp is finite (neither invalid nor infinity)</entry>
<entry>isfinite(timestamp '2001-02-16 21:28:30')</entry>
<entry>true</entry>
</row>
<row>
<entry>isfinite(interval)</entry>
<entry>boolean</entry>
<entry>Returns true if the interval is finite in length</entry>
<entry>isfinite(interval '4 hours')</entry>
<entry>true</entry>
</row>
<row>
<entry>now()</entry>
<entry>timestamp</entry>
<entry>
returns current date and time (equivalent to
<function>current_timestamp</function>); see also <link
linkend="functions-datetime-current">below</link>
</entry>
<entry></entry>
<entry></entry>
</row>
<row>
<entry>timestamp(date)</entry>
<entry>timestamp</entry>
<entry>convert date to timestamp</entry>
<entry>timestamp(date '2000-12-25')</entry>
<entry>2000-12-25 00:00:00</entry>
</row>
<row>
<entry>timestamp(date, time)</entry>
<entry>timestamp</entry>
<entry>combine date and time into a timestamp</entry>
<entry>timestamp(date '1998-02-24',time '23:07')</entry>
<entry>1998-02-24 23:07:00</entry>
</row>
</tbody>
</tgroup>
</table>
<sect2 id="functions-datetime-extract">
<title><function>EXTRACT</function>, <function>date_part</function></title>
<synopsis>
EXTRACT (<replaceable>field</replaceable> FROM <replaceable>source</replaceable>)
</synopsis>
<para>
The <function>extract</function> function retrieves sub-fields
from date/time values, such as year or hour.
<replaceable>source</replaceable> is a value expression that
evaluates to type <type>timestamp</type> or <type>interval</type>.
(Expressions of type <type>date</type> or <type>time</type> will
be cast to <type>timestamp</type> and can therefore be used as
well.) <replaceable>field</replaceable> is an identifier (not a
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 values:
<!-- alphabetical -->
<variablelist>
<varlistentry>
<term>century</term>
<listitem>
<para>
The year field divided by 100
</para>
<informalexample>
<screen>
SELECT EXTRACT(CENTURY FROM TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>20</computeroutput>
</screen>
</informalexample>
<para>
Note that this is not really the century that the date is in.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>day</term>
<listitem>
<para>
The day (of the month) field (1 - 31)
</para>
<informalexample>
<screen>
SELECT EXTRACT(DAY FROM TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>16</computeroutput>
</screen>
</informalexample>
</listitem>
</varlistentry>
<varlistentry>
<term>decade</term>
<listitem>
<para>
The year field divided by 10
</para>
<informalexample>
<screen>
SELECT EXTRACT(DECADE FROM TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>200</computeroutput>
</screen>
</informalexample>
</listitem>
</varlistentry>
<varlistentry>
<term>dow</term>
<listitem>
<para>
The day of the week (0 - 6; Sunday is 0) (for
<type>timestamp</type> values only)
</para>
<informalexample>
<screen>
SELECT EXTRACT(DOW FROM TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>5</computeroutput>
</screen>
</informalexample>
</listitem>
</varlistentry>
<varlistentry>
<term>doy</term>
<listitem>
<para>
The day of the year (1 - 365/366) (for <type>timestamp</type> values only)
</para>
<informalexample>
<screen>
SELECT EXTRACT(DOY FROM TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>47</computeroutput>
</screen>
</informalexample>
</listitem>
</varlistentry>
<varlistentry>
<term>epoch</term>
<listitem>
<para>
For <type>date</type> and <type>timestamp</type> values, the
number of seconds since 1970-01-01 00:00:00 (Result may be
negative.); for <type>interval</type> values, the total number
of seconds in the interval
</para>
<informalexample>
<screen>
SELECT EXTRACT(EPOCH FROM TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>982352320</computeroutput>
SELECT EXTRACT(EPOCH FROM INTERVAL '5 days 3 hours');
<lineannotation>Result: </lineannotation><computeroutput>442800</computeroutput>
</screen>
</informalexample>
</listitem>
</varlistentry>
<varlistentry>
<term>hour</term>
<listitem>
<para>
The hour field (0 - 23)
</para>
<informalexample>
<screen>
SELECT EXTRACT(HOUR FROM TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>20</computeroutput>
</screen>
</informalexample>
</listitem>
</varlistentry>
<varlistentry>
<term>microseconds</term>
<listitem>
<para>
The seconds field, including fractional parts, multiplied by 1
000 000. Note that this includes full seconds.
</para>
<informalexample>
<screen>
SELECT EXTRACT(MICROSECONDS FROM TIME '17:12:28.5');
<lineannotation>Result: </lineannotation><computeroutput>28500000</computeroutput>
</screen>
</informalexample>
</listitem>
</varlistentry>
<varlistentry>
<term>millennium</term>
<listitem>
<para>
The year field divided by 1000
</para>
<informalexample>
<screen>
SELECT EXTRACT(MILLENNIUM FROM TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>2</computeroutput>
</screen>
</informalexample>
<para>
Note that this is not really the millennium that the date is in.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>milliseconds</term>
<listitem>
<para>
The seconds field, including fractional parts, multiplied by
1000. Note that this includes full seconds.
</para>
<informalexample>
<screen>
SELECT EXTRACT(MILLISECONDS FROM TIME '17:12:28.5');
<lineannotation>Result: </lineannotation><computeroutput>28500</computeroutput>
</screen>
</informalexample>
</listitem>
</varlistentry>
<varlistentry>
<term>minute</term>
<listitem>
<para>
The minutes field (0 - 59)
</para>
<informalexample>
<screen>
SELECT EXTRACT(MINUTE FROM TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>38</computeroutput>
</screen>
</informalexample>
</listitem>
</varlistentry>
<varlistentry>
<term>month</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>
<informalexample>
<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>
</informalexample>
</listitem>
</varlistentry>
<varlistentry>
<term>quarter</term>
<listitem>
<para>
The quarter of the year (1 - 4) that the day is in (for
<type>timestamp</type> values only)
</para>
<informalexample>
<screen>
SELECT EXTRACT(QUARTER FROM TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
</screen>
</informalexample>
</listitem>
</varlistentry>
<varlistentry>
<term>second</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>
<informalexample>
<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>
</informalexample>
</listitem>
</varlistentry>
<varlistentry>
<term>week</term>
<listitem>
<para>
From a <type>timestamp</type> value, calculate the number of
the week of the year that the day is in. By definition
(<acronym>ISO</acronym> 8601), the first week of a year
contains January 4 of that year. (The <acronym>ISO</acronym>
week starts on Monday.) In other words, the first Thursday of
a year is in week 1 of that year.
</para>
<informalexample>
<screen>
SELECT EXTRACT(WEEK FROM TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>7</computeroutput>
</screen>
</informalexample>
</listitem>
</varlistentry>
<varlistentry>
<term>year</term>
<listitem>
<para>
The year field
</para>
<informalexample>
<screen>
SELECT EXTRACT(YEAR FROM TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>2001</computeroutput>
</screen>
</informalexample>
</listitem>
</varlistentry>
<!--
tz
tz_hour
tz_minute
-->
</variablelist>
</para>
<para>
The <function>extract</function> function is primarily intended
for computational processing. For formatting date/time values for
display, see <xref linkend="functions-formatting">.
</para>
<anchor id="functions-datetime-datepart">
<para>
The <function>date_part</function> function is the traditional
<productname>Postgres</productname> equivalent to the
<acronym>SQL</acronym>-function <function>extract</function>:
<synopsis>
date_part('<replaceable>field</replaceable>', <replaceable>source</replaceable>)
</synopsis>
Note that here the <replaceable>field</replaceable> value needs to
be a string. The valid field values for
<function>date_part</function> are the same as for
<function>extract</function>.
</para>
<informalexample>
<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>
</informalexample>
</sect2>
<sect2 id="functions-datetime-trunc">
<title><function>date_trunc</function></title>
<para>
The function <function>date_trunc</function> is conceptually
similar to the <function>trunc</function> function for numbers.
</para>
<para>
<synopsis>
date_trunc('<replaceable>field</replaceable>', <replaceable>source</replaceable>)
</synopsis>
<replaceable>source</replaceable> is a value expression of type
<type>timestamp</type> (values of type <type>date</type> and
<type>time</type> are cast automatically).
<replaceable>field</replaceable> selects to which precision to
truncate the time stamp value. The return value is of type
<type>timestamp</type> with all fields that are less than the
selected one set to zero (or one, for day and month).
</para>
<para>
Valid values for <replaceable>field</replaceable> are:
<simplelist>
<member>microseconds</member>
<member>milliseconds</member>
<member>second</member>
<member>minute</member>
<member>hour</member>
<member>day</member>
<member>month</member>
<member>year</member>
<member>decade</member>
<member>century</member>
<member>millennium</member>
</simplelist>
</para>
<informalexample>
<para>
<screen>
SELECT date_trunc('hour', TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>2001-02-16 20:00:00+00</computeroutput>
SELECT date_trunc('year', TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>2001-01-01 00:00:00+00</computeroutput>
</screen>
</para>
</informalexample>
</sect2>
<sect2 id="functions-datetime-current">
<title>Current Date/Time</title>
<para>
The following functions are available to select the current date and/or time:
<synopsis>
CURRENT_TIME
CURRENT_DATE
CURRENT_TIMESTAMP
</synopsis>
Note that because of the requirements of the
<acronym>SQL</acronym> standard, these functions must not be
called with trailing parentheses.
</para>
<informalexample>
<screen>
SELECT CURRENT_TIME;
<computeroutput>19:07:13</computeroutput>
SELECT CURRENT_DATE;
<computeroutput>2001-02-17</computeroutput>
SELECT CURRENT_TIMESTAMP;
<computeroutput>2001-02-17 19:07:32+00</computeroutput>
</screen>
</informalexample>
<para>
The function <function>now()</function> is the traditional
<productname>Postgres</productname> equivalent to
<function>CURRENT_TIMESTAMP</function>.
<productname>Postgres</productname> furthermore has special
date/time <quote>constants</quote> that can be used to specify the
current time. The following three all return the same result:
<programlisting>
SELECT CURRENT_TIMESTAMP;
SELECT now();
SELECT TIMESTAMP 'now';
</programlisting>
<note>
<para>
You do not want to use the third form when specifying a DEFAULT
value when creating a table. The system will immediately
evaluate the constant, thus 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.
</para>
</note>
</para>
</sect2>
</sect1>
<sect1 id="functions-geometry">
<title>Geometric Functions and Operators</title>
<para>
The geometric types point, box, lseg, line, path, polygon, and
circle have a large set of native support functions and operators.
</para>
<table>
<TITLE>Geometric Operators</TITLE>
<TGROUP COLS="3">
<THEAD>
<ROW>
<ENTRY>Operator</ENTRY>
<ENTRY>Description</ENTRY>
<ENTRY>Usage</ENTRY>
</ROW>
</THEAD>
<TBODY>
<ROW>
<ENTRY> + </ENTRY>
<ENTRY>Translation</ENTRY>
<ENTRY>box '((0,0),(1,1))' + point '(2.0,0)'</ENTRY>
</ROW>
<ROW>
<ENTRY> - </ENTRY>
<ENTRY>Translation</ENTRY>
<ENTRY>box '((0,0),(1,1))' - point '(2.0,0)'</ENTRY>
</ROW>
<ROW>
<ENTRY> * </ENTRY>
<ENTRY>Scaling/rotation</ENTRY>
<ENTRY>box '((0,0),(1,1))' * point '(2.0,0)'</ENTRY>
</ROW>
<ROW>
<ENTRY> / </ENTRY>
<ENTRY>Scaling/rotation</ENTRY>
<ENTRY>box '((0,0),(2,2))' / point '(2.0,0)'</ENTRY>
</ROW>
<ROW>
<ENTRY> # </ENTRY>
<ENTRY>Intersection</ENTRY>
<ENTRY>'((1,-1),(-1,1))' # '((1,1),(-1,-1))'</ENTRY>
</ROW>
<ROW>
<ENTRY> # </ENTRY>
<ENTRY>Number of points in polygon</ENTRY>
<ENTRY># '((1,0),(0,1),(-1,0))'</ENTRY>
</ROW>
<ROW>
<ENTRY> ## </ENTRY>
<ENTRY>Point of closest proximity</ENTRY>
<ENTRY>point '(0,0)' ## lseg '((2,0),(0,2))'</ENTRY>
</ROW>
<ROW>
<ENTRY> &amp;&amp; </ENTRY>
<ENTRY>Overlaps?</ENTRY>
<ENTRY>box '((0,0),(1,1))' &amp;&amp; box '((0,0),(2,2))'</ENTRY>
</ROW>
<ROW>
<ENTRY> &amp;&lt; </ENTRY>
<ENTRY>Overlaps to left?</ENTRY>
<ENTRY>box '((0,0),(1,1))' &amp;&lt; box '((0,0),(2,2))'</ENTRY>
</ROW>
<ROW>
<ENTRY> &amp;&gt; </ENTRY>
<ENTRY>Overlaps to right?</ENTRY>
<ENTRY>box '((0,0),(3,3))' &amp;&gt; box '((0,0),(2,2))'</ENTRY>
</ROW>
<ROW>
<ENTRY> &lt;-&gt; </ENTRY>
<ENTRY>Distance between</ENTRY>
<ENTRY>circle '((0,0),1)' &lt;-&gt; circle '((5,0),1)'</ENTRY>
</ROW>
<ROW>
<ENTRY> &lt;&lt; </ENTRY>
<ENTRY>Left of?</ENTRY>
<ENTRY>circle '((0,0),1)' &lt;&lt; circle '((5,0),1)'</ENTRY>
</ROW>
<ROW>
<ENTRY> &lt;^ </ENTRY>
<ENTRY>Is below?</ENTRY>
<ENTRY>circle '((0,0),1)' &lt;^ circle '((0,5),1)'</ENTRY>
</ROW>
<ROW>
<ENTRY> &gt;&gt; </ENTRY>
<ENTRY>Is right of?</ENTRY>
<ENTRY>circle '((5,0),1)' &gt;&gt; circle '((0,0),1)'</ENTRY>
</ROW>
<ROW>
<ENTRY> &gt;^ </ENTRY>
<ENTRY>Is above?</ENTRY>
<ENTRY>circle '((0,5),1)' >^ circle '((0,0),1)'</ENTRY>
</ROW>
<ROW>
<ENTRY> ?# </ENTRY>
<ENTRY>Intersects or overlaps</ENTRY>
<ENTRY>lseg '((-1,0),(1,0))' ?# box '((-2,-2),(2,2))';</ENTRY>
</ROW>
<ROW>
<ENTRY> ?- </ENTRY>
<ENTRY>Is horizontal?</ENTRY>
<ENTRY>point '(1,0)' ?- point '(0,0)'</ENTRY>
</ROW>
<ROW>
<ENTRY> ?-| </ENTRY>
<ENTRY>Is perpendicular?</ENTRY>
<ENTRY>lseg '((0,0),(0,1))' ?-| lseg '((0,0),(1,0))'</ENTRY>
</ROW>
<ROW>
<ENTRY> @-@ </ENTRY>
<ENTRY>Length or circumference</ENTRY>
<ENTRY>@-@ path '((0,0),(1,0))'</ENTRY>
</ROW>
<ROW>
<ENTRY> ?| </ENTRY>
<ENTRY>Is vertical?</ENTRY>
<ENTRY>point '(0,1)' ?| point '(0,0)'</ENTRY>
</ROW>
<ROW>
<ENTRY> ?|| </ENTRY>
<ENTRY>Is parallel?</ENTRY>
<ENTRY>lseg '((-1,0),(1,0))' ?|| lseg '((-1,2),(1,2))'</ENTRY>
</ROW>
<ROW>
<ENTRY> @ </ENTRY>
<ENTRY>Contained or on</ENTRY>
<ENTRY>point '(1,1)' @ circle '((0,0),2)'</ENTRY>
</ROW>
<ROW>
<ENTRY> @@ </ENTRY>
<ENTRY>Center of</ENTRY>
<ENTRY>@@ circle '((0,0),10)'</ENTRY>
</ROW>
<ROW>
<ENTRY> ~= </ENTRY>
<ENTRY>Same as</ENTRY>
<ENTRY>polygon '((0,0),(1,1))' ~= polygon '((1,1),(0,0))'</ENTRY>
</ROW>
</TBODY>
</TGROUP>
</TABLE>
<table>
1999-06-14 09:36:12 +02:00
<title>Geometric Functions</title>
<tgroup cols="4">
<thead>
<row>
<entry>Function</entry>
<entry>Returns</entry>
<entry>Description</entry>
<entry>Example</entry>
</row>
</thead>
<tbody>
<row>
<entry>area(object)</entry>
<entry>double precision</entry>
<entry>area of item</entry>
<entry>area(box '((0,0),(1,1))')</entry>
1999-06-14 09:36:12 +02:00
</row>
<row>
<entry>box(box, box)</entry>
<entry>box</entry>
<entry>intersection box</entry>
<entry>box(box '((0,0),(1,1))',box '((0.5,0.5),(2,2))')</entry>
1999-06-14 09:36:12 +02:00
</row>
<row>
<entry>center(object)</entry>
<entry>point</entry>
<entry>center of item</entry>
<entry>center(box '((0,0),(1,2))')</entry>
1999-06-14 09:36:12 +02:00
</row>
<row>
<entry>diameter(circle)</entry>
<entry>double precision</entry>
<entry>diameter of circle</entry>
<entry>diameter(circle '((0,0),2.0)')</entry>
1999-06-14 09:36:12 +02:00
</row>
<row>
<entry>height(box)</entry>
<entry>double precision</entry>
<entry>vertical size of box</entry>
<entry>height(box '((0,0),(1,1))')</entry>
1999-06-14 09:36:12 +02:00
</row>
<row>
<entry>isclosed(path)</entry>
<entry>boolean</entry>
<entry>a closed path?</entry>
<entry>isclosed(path '((0,0),(1,1),(2,0))')</entry>
1999-06-14 09:36:12 +02:00
</row>
<row>
<entry>isopen(path)</entry>
<entry>boolean</entry>
<entry>an open path?</entry>
<entry>isopen(path '[(0,0),(1,1),(2,0)]')</entry>
1999-06-14 09:36:12 +02:00
</row>
<row>
<entry>length(object)</entry>
<entry>double precision</entry>
<entry>length of item</entry>
<entry>length(path '((-1,0),(1,0))')</entry>
1999-06-14 09:36:12 +02:00
</row>
<row>
<entry>pclose(path)</entry>
<entry>path</entry>
<entry>convert path to closed</entry>
<entry>popen(path '[(0,0),(1,1),(2,0)]')</entry>
1999-06-14 09:36:12 +02:00
</row>
<!--
Not defined by this name. Implements the intersection operator '#'
1999-06-14 09:36:12 +02:00
<row>
<entry>point(lseg,lseg)</entry>
<entry>point</entry>
<entry>intersection</entry>
<entry>point(lseg '((-1,0),(1,0))',lseg '((-2,-2),(2,2))')</entry>
1999-06-14 09:36:12 +02:00
</row>
-->
1999-06-14 09:36:12 +02:00
<row>
<entry>npoint(path)</entry>
<entry>int4</entry>
<entry>number of points</entry>
<entry>npoints(path '[(0,0),(1,1),(2,0)]')</entry>
1999-06-14 09:36:12 +02:00
</row>
<row>
<entry>popen(path)</entry>
<entry>path</entry>
<entry>convert path to open path</entry>
<entry>popen(path '((0,0),(1,1),(2,0))')</entry>
1999-06-14 09:36:12 +02:00
</row>
<row>
<entry>radius(circle)</entry>
<entry>double precision</entry>
<entry>radius of circle</entry>
<entry>radius(circle '((0,0),2.0)')</entry>
1999-06-14 09:36:12 +02:00
</row>
<row>
<entry>width(box)</entry>
<entry>double precision</entry>
<entry>horizontal size</entry>
<entry>width(box '((0,0),(1,1))')</entry>
1999-06-14 09:36:12 +02:00
</row>
</tbody>
</tgroup>
</table>
<table>
1999-06-14 09:36:12 +02:00
<title>Geometric Type Conversion Functions</title>
<tgroup cols="4">
<thead>
<row>
<entry>Function</entry>
<entry>Returns</entry>
<entry>Description</entry>
<entry>Example</entry>
</row>
</thead>
<tbody>
<row>
<entry>box(circle)</entry>
<entry>box</entry>
<entry>circle to box</entry>
<entry>box(circle '((0,0),2.0)')</entry>
1999-06-14 09:36:12 +02:00
</row>
<row>
<entry>box(point, point)</entry>
<entry>box</entry>
<entry>points to box</entry>
<entry>box(point '(0,0)', point '(1,1)')</entry>
1999-06-14 09:36:12 +02:00
</row>
<row>
<entry>box(polygon)</entry>
<entry>box</entry>
<entry>polygon to box</entry>
<entry>box(polygon '((0,0),(1,1),(2,0))')</entry>
1999-06-14 09:36:12 +02:00
</row>
<row>
<entry>circle(box)</entry>
<entry>circle</entry>
<entry>to circle</entry>
<entry>circle(box '((0,0),(1,1))')</entry>
1999-06-14 09:36:12 +02:00
</row>
<row>
<entry>circle(point, double precision)</entry>
<entry>circle</entry>
<entry>point to circle</entry>
<entry>circle(point '(0,0)', 2.0)</entry>
1999-06-14 09:36:12 +02:00
</row>
<row>
<entry>lseg(box)</entry>
<entry>lseg</entry>
<entry>box diagonal to lseg</entry>
<entry>lseg(box '((-1,0),(1,0))')</entry>
1999-06-14 09:36:12 +02:00
</row>
<row>
<entry>lseg(point, point)</entry>
<entry>lseg</entry>
<entry>points to lseg</entry>
<entry>lseg(point '(-1,0)', point '(1,0)')</entry>
1999-06-14 09:36:12 +02:00
</row>
<row>
<entry>path(polygon)</entry>
<entry>point</entry>
<entry>polygon to path</entry>
<entry>path(polygon '((0,0),(1,1),(2,0))')</entry>
1999-06-14 09:36:12 +02:00
</row>
<row>
<entry>point(circle)</entry>
<entry>point</entry>
<entry>center</entry>
<entry>point(circle '((0,0),2.0)')</entry>
1999-06-14 09:36:12 +02:00
</row>
<row>
<entry>point(lseg, lseg)</entry>
<entry>point</entry>
<entry>intersection</entry>
<entry>point(lseg '((-1,0),(1,0))', lseg '((-2,-2),(2,2))')</entry>
1999-06-14 09:36:12 +02:00
</row>
<row>
<entry>point(polygon)</entry>
<entry>point</entry>
<entry>center</entry>
<entry>point(polygon '((0,0),(1,1),(2,0))')</entry>
1999-06-14 09:36:12 +02:00
</row>
<row>
<entry>polygon(box)</entry>
<entry>polygon</entry>
<entry>12 point polygon</entry>
<entry>polygon(box '((0,0),(1,1))')</entry>
1999-06-14 09:36:12 +02:00
</row>
<row>
<entry>polygon(circle)</entry>
<entry>polygon</entry>
<entry>12-point polygon</entry>
<entry>polygon(circle '((0,0),2.0)')</entry>
1999-06-14 09:36:12 +02:00
</row>
<row>
<entry>polygon(<replaceable class="parameter">npts</replaceable>, circle)</entry>
<entry>polygon</entry>
<entry><replaceable class="parameter">npts</replaceable> polygon</entry>
<entry>polygon(12, circle '((0,0),2.0)')</entry>
1999-06-14 09:36:12 +02:00
</row>
<row>
<entry>polygon(path)</entry>
<entry>polygon</entry>
<entry>path to polygon</entry>
<entry>polygon(path '((0,0),(1,1),(2,0))')</entry>
1999-06-14 09:36:12 +02:00
</row>
</tbody>
</tgroup>
</table>
</sect1>
<sect1 id="functions-net">
<title>Network Address Type Functions</title>
1998-10-27 07:14:41 +01:00
<table tocentry="1" id="cidr-inet-operators-table">
<title><type>cidr</> and <type>inet</> Operators</title>
<TGROUP COLS="3">
<THEAD>
<ROW>
<ENTRY>Operator</ENTRY>
<ENTRY>Description</ENTRY>
<ENTRY>Usage</ENTRY>
</ROW>
</THEAD>
<TBODY>
<ROW>
<ENTRY> &lt; </ENTRY>
<ENTRY>Less than</ENTRY>
<ENTRY>inet '192.168.1.5' &lt; inet '192.168.1.6'</ENTRY>
</ROW>
<ROW>
<ENTRY> &lt;= </ENTRY>
<ENTRY>Less than or equal</ENTRY>
<ENTRY>inet '192.168.1.5' &lt;= inet '192.168.1.5'</ENTRY>
</ROW>
<ROW>
<ENTRY> = </ENTRY>
<ENTRY>Equals</ENTRY>
<ENTRY>inet '192.168.1.5' = inet '192.168.1.5'</ENTRY>
</ROW>
<ROW>
<ENTRY> &gt;= </ENTRY>
<ENTRY>Greater or equal</ENTRY>
<ENTRY>inet '192.168.1.5' &gt;= inet '192.168.1.5'</ENTRY>
</ROW>
<ROW>
<ENTRY> &gt; </ENTRY>
<ENTRY>Greater</ENTRY>
<ENTRY>inet '192.168.1.5' &gt; inet '192.168.1.4'</ENTRY>
</ROW>
<ROW>
<ENTRY> &lt;&gt; </ENTRY>
<ENTRY>Not equal</ENTRY>
<ENTRY>inet '192.168.1.5' &lt;&gt; inet '192.168.1.4'</ENTRY>
</ROW>
<ROW>
<ENTRY> &lt;&lt; </ENTRY>
<ENTRY>is contained within</ENTRY>
<ENTRY>inet '192.168.1.5' &lt;&lt; inet '192.168.1/24'</ENTRY>
</ROW>
<ROW>
<ENTRY> &lt;&lt;= </ENTRY>
<ENTRY>is contained within or equals</ENTRY>
<ENTRY>inet '192.168.1/24' &lt;&lt;= inet '192.168.1/24'</ENTRY>
</ROW>
<ROW>
<ENTRY> &gt;&gt; </ENTRY>
<ENTRY>contains</ENTRY>
<ENTRY>inet'192.168.1/24' &gt;&gt; inet '192.168.1.5'</ENTRY>
</ROW>
<ROW>
<ENTRY> &gt;&gt;= </ENTRY>
<ENTRY>contains or equals</ENTRY>
<ENTRY>inet '192.168.1/24' &gt;&gt;= inet '192.168.1/24'</ENTRY>
</ROW>
</TBODY>
</TGROUP>
</TABLE>
<para>
All of the operators for <type>inet</type> can be applied to
<type>cidr</type> values as well. The operators
<literal>&lt;&lt;</>, <literal>&lt;&lt;=</>,
<literal>&gt;&gt;</>, <literal>&gt;&gt;=</>
test for subnet inclusion: they consider only the network parts
of the two addresses, ignoring any host part, and determine whether
one network part is identical to or a subnet of the other.
</para>
<table tocentry="1" id="cidr-inet-functions">
<title><type>cidr</> and <type>inet</> Functions</title>
<tgroup cols="5">
1999-06-14 09:36:12 +02:00
<thead>
<row>
<entry>Function</entry>
<entry>Returns</entry>
<entry>Description</entry>
<entry>Example</entry>
<entry>Result</entry>
1999-06-14 09:36:12 +02:00
</row>
</thead>
<tbody>
<row>
<entry>broadcast(inet)</entry>
<entry>inet</entry>
<entry>broadcast address for network</entry>
<entry>broadcast('192.168.1.5/24')</entry>
<entry>192.168.1.255/24</entry>
1999-06-14 09:36:12 +02:00
</row>
<row>
<entry>host(inet)</entry>
<entry>text</entry>
<entry>extract IP address as text</entry>
<entry>host('192.168.1.5/24')</entry>
<entry>192.168.1.5</entry>
1999-06-14 09:36:12 +02:00
</row>
<row>
<entry>masklen(inet)</entry>
<entry>integer</entry>
<entry>extract netmask length</entry>
<entry>masklen('192.168.1.5/24')</entry>
<entry>24</entry>
1999-06-14 09:36:12 +02:00
</row>
<row>
<entry>netmask(inet)</entry>
<entry>inet</entry>
<entry>construct netmask for network</entry>
<entry>netmask('192.168.1.5/24')</entry>
<entry>255.255.255.0</entry>
</row>
<row>
<entry>network(inet)</entry>
<entry>cidr</entry>
<entry>extract network part of address</entry>
<entry>network('192.168.1.5/24')</entry>
<entry>192.168.1.0/24</entry>
</row>
<row>
<entry>text(inet)</entry>
<entry>text</entry>
<entry>extract IP address and masklen as text</entry>
<entry>text(inet '192.168.1.5')</entry>
<entry>192.168.1.5/32</entry>
</row>
<row>
<entry>abbrev(inet)</entry>
<entry>text</entry>
<entry>extract abbreviated display as text</entry>
<entry>abbrev(cidr '10.1.0.0/16')</entry>
<entry>10.1/16</entry>
</row>
</tbody>
</tgroup>
</table>
<para>
All of the functions for <type>inet</type> can be applied to
<type>cidr</type> values as well. The <function>host</>(),
<function>text</>(), and <function>abbrev</>() functions are primarily
intended to offer alternative display formats.
</para>
<para>
<table tocentry="1" id="macaddr-functions">
<title><type>macaddr</> Functions</title>
<tgroup cols="5">
<thead>
<row>
<entry>Function</entry>
<entry>Returns</entry>
<entry>Description</entry>
<entry>Example</entry>
<entry>Result</entry>
1999-06-14 09:36:12 +02:00
</row>
</thead>
<tbody>
<row>
<entry>trunc(macaddr)</entry>
<entry>macaddr</entry>
<entry>set last 3 bytes to zero</entry>
<entry>trunc(macaddr '12:34:56:78:90:ab')</entry>
<entry>12:34:56:00:00:00</entry>
</row>
1999-06-14 09:36:12 +02:00
</tbody>
</tgroup>
</table>
</para>
<para>
The function <function>trunc</>(<type>macaddr</>) returns a MAC
address with the last 3 bytes set to 0. This can be used to
associate the remaining prefix with a manufacturer. The directory
<filename>contrib/mac</> in the source distribution contains some
utilities to create and maintain such an association table.
1999-06-14 09:36:12 +02:00
</para>
1998-10-27 07:14:41 +01:00
<para>
The <type>macaddr</> type also supports the standard relational
operators (<literal>&gt;</>, <literal>&lt;=</>, etc.) for
lexicographical ordering.
</para>
1999-06-14 09:36:12 +02:00
</sect1>
1998-10-27 07:14:41 +01:00
<sect1 id="functions-conditional">
<title>Conditional Expressions</title>
<para>
This section describes the <acronym>SQL</acronym>-compliant conditional expressions
available in <productname>Postgres</productname>.
</para>
<tip>
<para>
If your needs go beyond the capabilities of these conditional
expressions you might want to consider writing a stored procedure
in a more expressive programming language.
</para>
</tip>
<bridgehead renderas="sect2">CASE</bridgehead>
<synopsis>
CASE WHEN <replaceable>condition</replaceable> THEN <replaceable>result</replaceable>
<optional>WHEN ...</optional>
<optional>ELSE <replaceable>result</replaceable></optional>
END
</synopsis>
<para>
The <acronym>SQL</acronym> <token>CASE</token> expression is a
generic conditional expression, similar to if/else statements in
other languages. <token>CASE</token> clauses can be used wherever
an expression is valid. <replaceable>condition</replaceable> is an
expression that returns a <type>boolean</type> result. If the result is true
then the value of the <token>CASE</token> expression is
<replaceable>result</replaceable>. If the result is false any
subsequent <token>WHEN</token> clauses are searched in the same
manner. If no <token>WHEN</token>
<replaceable>condition</replaceable> is true then the value of the
case expression is the <replaceable>result</replaceable> in the
<token>ELSE</token> clause. If the <token>ELSE</token> clause is
omitted and no condition matches, the result is NULL.
</para>
<informalexample>
<para>
An example:
<screen>
<prompt>=&gt;</prompt> <userinput>SELECT * FROM test;</userinput>
<computeroutput>
a
---
1
2
3
</computeroutput>
<prompt>=&gt;</prompt> <userinput>SELECT a, CASE WHEN a=1 THEN 'one' WHEN a=2 THEN 'two' ELSE 'other' END FROM test;</userinput>
<computeroutput>
a | case
---+-------
1 | one
2 | two
3 | other
</computeroutput>
</screen>
</para>
</informalexample>
<para>
The data types of all the <replaceable>result</replaceable>
expressions must be coercible to a single output type.
See <xref linkend="typeconv-union-case"> for more detail.
</para>
<synopsis>
CASE <replaceable>expression</replaceable>
WHEN <replaceable>value</replaceable> THEN <replaceable>result</replaceable>
<optional>WHEN ...</optional>
<optional>ELSE <replaceable>result</replaceable></optional>
END
</synopsis>
<para>
This <quote>simple</quote> <token>CASE</token> expression is a
specialized variant of the general form above. The
<replaceable>expression</replaceable> is computed and compared to
all the <replaceable>value</replaceable>s in the
<token>WHEN</token> clauses until one is found that is equal. If
no match is found, the <replaceable>result</replaceable> in the
<token>ELSE</token> clause (or NULL) is returned. This is similar
to the <function>switch</function> statement in C.
</para>
<informalexample>
<para>
The example above can be written using the simple
<token>CASE</token> syntax:
<screen>
<prompt>=&gt;</prompt> <userinput>SELECT a, CASE a WHEN 1 THEN 'one' WHEN 2 THEN 'two' ELSE 'other' END FROM test;</userinput>
<computeroutput>
a | case
---+-------
1 | one
2 | two
3 | other
</computeroutput>
</screen>
</para>
</informalexample>
<bridgehead renderas="sect2">COALESCE</bridgehead>
<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. This is often useful to substitute a
default value for NULL values when data is retrieved for display,
for example:
<programlisting>
SELECT COALESCE(description, short_description, '(none)') ...
</programlisting>
</para>
<bridgehead renderas="sect2">NULLIF</bridgehead>
<synopsis>
<function>NULLIF</function>(<replaceable>value1</replaceable>, <replaceable>value2</replaceable>)
</synopsis>
<para>
The <function>NULLIF</function> function returns NULL if and only
if <replaceable>value1</replaceable> and
<replaceable>value2</replaceable> are equal. 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>
<tip>
<para>
<function>COALESCE</function> and <function>NULLIF</function> are
just shorthand for <token>CASE</token> expressions. They are actually
converted into <token>CASE</token> expressions at a very early stage
of processing, and subsequent processing thinks it is dealing with
<token>CASE</token>. Thus an incorrect <function>COALESCE</function> or
<function>NULLIF</function> usage may draw an error message that
refers to <token>CASE</token>.
</para>
</tip>
</sect1>
<sect1 id="functions-misc">
<title>Miscellaneous Functions</>
<table>
<title>Miscellaneous Functions</>
<tgroup cols="3">
<thead>
<row><entry>Name</> <entry>Return type</> <entry>Description</></row>
</thead>
<tbody>
<row>
<entry>current_user</>
<entry>name</>
<entry>user name of current execution context</>
</row>
<row>
<entry>session_user</>
<entry>name</>
<entry>session user name</>
</row>
<row>
<entry>user</>
<entry>name</>
<entry>equivalent to <function>current_user</></>
</row>
</tbody>
</tgroup>
</table>
<para>
The <function>session_user</> is the user that initiated a database
connection and is fixed for the duration of that connection. The
<function>current_user</> is the user identifier that is applicable
for permission checking. Currently it is always equal to the session
user, but in the future there might be <quote>setuid</> functions and
other facilities to allow the current user to change temporarily.
In Unix parlance, the session user is the <quote>real user</>
and the current user is the <quote>effective user</>.
</para>
<para>
Note that these functions have special syntactic status in <acronym>SQL</>;
they must be called without trailing parentheses.
</para>
<note>
<title>Deprecated</>
<para>
The function <function>getpgusername()</> is an obsolete equivalent
of <function>current_user</>.
</para>
</note>
</sect1>
<sect1 id="functions-aggregate">
<title>Aggregate Functions</title>
<note>
<title>Author</title>
<para>
Written by Isaac Wilcox <email>isaac@azartmedia.com</email> on 2000-06-16
</para>
</note>
<para>
<firstterm>Aggregate functions</firstterm> compute a single result
value from a set of input values. The special syntax
considerations for aggregate functions are explained in <xref
linkend="syntax-aggregates">. Consult the <citetitle>PostgreSQL
Tutorial</citetitle> for additional introductory information.
</para>
<table tocentry="1">
<title>Aggregate Functions</title>
<tgroup cols="3">
<thead>
<row>
<entry>Function</entry>
<entry>Description</entry>
<entry>Notes</entry>
</row>
</thead>
<tbody>
<row>
<entry>AVG(<replaceable class="parameter">expression</replaceable>)</entry>
<entry>the average (arithmetic mean) of all input values</entry>
<entry>
Finding the average value is available on the following data
types: <type>smallint</type>, <type>integer</type>,
<type>bigint</type>, <type>real</type>, <type>double
precision</type>, <type>numeric</type>, <type>interval</type>.
The result is of type <type>numeric</type> for any integer type
input, <type>double precision</type> for floating point input,
otherwise the same as the input data type.
</entry>
</row>
<row>
<entry>COUNT(*)</entry>
<entry>number of input values</entry>
<entry>The return value is of type <type>integer</type>.</entry>
</row>
<row>
<entry>COUNT(<replaceable class="parameter">expression</replaceable>)</entry>
<entry>
Counts the input values for which the value of <replaceable
class="parameter">expression</replaceable> is not NULL.
</entry>
<entry></entry>
</row>
<row>
<entry>MAX(<replaceable class="parameter">expression</replaceable>)</entry>
<entry>the maximum value of <replaceable class="parameter">expression</replaceable> across all input values</entry>
<entry>
Available for all numeric, string, and date/time types. The
result has the same type as the input expression.
</entry>
</row>
<row>
<entry>MIN(<replaceable class="parameter">expression</replaceable>)</entry>
<entry>the minimum value of <replaceable class="parameter">expression</replaceable> across all input values</entry>
<entry>
Available for all numeric, string, and date/time types. The
result has the same type as the input expression.
</entry>
</row>
<row>
<entry>STDDEV(<replaceable class="parameter">expression</replaceable>)</entry>
<entry>the sample standard deviation of the input values</entry>
<entry>
Finding the standard deviation is available on the following
data types: <type>smallint</type>, <type>integer</type>,
<type>bigint</type>, <type>real</type>, <type>double
precision</type>, <type>numeric</type>. The result is of type
<type>double precision</type> for floating point input,
otherwise <type>numeric</type>.
</entry>
</row>
<row>
<entry>SUM(<replaceable class="parameter">expression</replaceable>)</entry>
<entry>sum of <replaceable class="parameter">expression</replaceable> across all input values</entry>
<entry>
Summation is available on the following data types:
<type>smallint</type>, <type>integer</type>,
<type>bigint</type>, <type>real</type>, <type>double
precision</type>, <type>numeric</type>, <type>interval</type>.
The result is of type <type>numeric</type> for any integer type
input, <type>double precision</type> for floating point input,
otherwise the same as the input data type.
</entry>
</row>
<row>
<entry>VARIANCE(<replaceable class="parameter">expression</replaceable>)</entry>
<entry>the sample variance of the input values</entry>
<entry>
The variance is the square of the standard deviation. The
supported data types are the same.
</entry>
</row>
</tbody>
</tgroup>
</table>
<para>
It should be noted that except for <function>COUNT</function>,
these functions return NULL when no rows are selected. In
particular, <function>SUM</function> of no rows returns NULL, not
zero as one might expect.
</para>
</sect1>
</chapter>
<!-- Keep this comment at the end of the file
Local variables:
mode:sgml
sgml-omittag:nil
sgml-shorttag:t
sgml-minimize-attributes:nil
sgml-always-quote-attributes:t
sgml-indent-step:1
sgml-indent-data:t
sgml-parent-document:nil
sgml-default-dtd-file:"./reference.ced"
sgml-exposed-tags:nil
sgml-local-catalogs:("/usr/lib/sgml/catalog")
sgml-local-ecat-files:nil
End:
-->