-<!-- $Header: /cvsroot/pgsql/doc/src/sgml/array.sgml,v 1.22 2002/09/21 18:32:52 petere Exp $ -->
+<!-- $Header: /cvsroot/pgsql/doc/src/sgml/array.sgml,v 1.22.2.1 2002/11/10 12:45:41 petere Exp $ -->
<sect1 id="arrays">
<title>Arrays</title>
</programlisting>
As shown, an array data type is named by appending square brackets
(<literal>[]</>) to the data type name of the array elements.
- The above query will create a table named
+ The above command will create a table named
<structname>sal_emp</structname> with columns including
a <type>text</type> string (<structfield>name</structfield>),
a one-dimensional array of type
The array subscript numbers are written within square brackets.
By default <productname>PostgreSQL</productname> uses the
- <quote>one-based</quote> numbering convention for arrays, that is,
+ one-based numbering convention for arrays, that is,
an array of <replaceable>n</> elements starts with <literal>array[1]</literal> and
ends with <literal>array[<replaceable>n</>]</literal>.
</para>
<para>
We can also access arbitrary rectangular slices of an array, or
subarrays. An array slice is denoted by writing
- <literal><replaceable>lower subscript</replaceable> :
- <replaceable>upper subscript</replaceable></literal> for one or more
- array dimensions. This query retrieves the first item on Bill's
- schedule for the first two days of the week:
+ <literal><replaceable>lower-bound</replaceable>:<replaceable>upper-bound</replaceable></literal>
+ for one or more array dimensions. This query retrieves the first
+ item on Bill's schedule for the first two days of the week:
<programlisting>
SELECT schedule[1:2][1:1] FROM sal_emp WHERE name = 'Bill';
with the same result. An array subscripting operation is taken to
represent an array slice if any of the subscripts are written in the
- form <replaceable>lower</replaceable> <literal>:</literal>
- <replaceable>upper</replaceable>. A lower bound of 1 is assumed for
- any subscript where only one value is specified.
+ form
+ <literal><replaceable>lower</replaceable>:<replaceable>upper</replaceable></literal>.
+ A lower bound of 1 is assumed for any subscript where only one value
+ is specified.
</para>
<para>
<tip>
<para>
- Remember that what you write in an SQL query will first be interpreted
+ Remember that what you write in an SQL command will first be interpreted
as a string literal, and then as an array. This doubles the number of
backslashes you need. For example, to insert a <type>text</> array
value containing a backslash and a double quote, you'd need to write
become <literal>\</> and <literal>"</> respectively. (If we were working
with a data type whose input routine also treated backslashes specially,
<type>bytea</> for example, we might need as many as eight backslashes
- in the query to get one backslash into the stored array element.)
+ in the command to get one backslash into the stored array element.)
</para>
</tip>
<!--
-$Header: /cvsroot/pgsql/doc/src/sgml/datatype.sgml,v 1.106 2002/10/31 22:18:42 tgl Exp $
+$Header: /cvsroot/pgsql/doc/src/sgml/datatype.sgml,v 1.106.2.1 2002/11/10 12:45:41 petere Exp $
-->
<chapter id="datatype">
<row>
<entry><type>money</type></entry>
<entry></entry>
- <entry>US-style currency</entry>
+ <entry>currency amount</entry>
</row>
<row>
<para>
Numeric types consist of two-, four-, and eight-byte integers,
- four- and eight-byte
- floating-point numbers and fixed-precision decimals.
+ four- and eight-byte floating-point numbers, and fixed-precision
+ decimals. <xref linkend="datatype-numeric-table"> lists the
+ available types.
</para>
- <para>
- <table tocentry="1">
+ <table id="datatype-numeric-table">
<title>Numeric Types</title>
<tgroup cols="4">
<thead>
<row>
<entry><type>smallint</></entry>
<entry>2 bytes</entry>
- <entry>Fixed-precision</entry>
+ <entry>small range fixed-precision</entry>
<entry>-32768 to +32767</entry>
</row>
<row>
<entry><type>integer</></entry>
<entry>4 bytes</entry>
- <entry>Usual choice for fixed-precision</entry>
+ <entry>usual choice for fixed-precision</entry>
<entry>-2147483648 to +2147483647</entry>
</row>
<row>
<entry><type>bigint</></entry>
<entry>8 bytes</entry>
- <entry>Very large range fixed-precision</entry>
+ <entry>large range fixed-precision</entry>
<entry>-9223372036854775808 to 9223372036854775807</entry>
</row>
<row>
<entry><type>bigserial</type></entry>
<entry>8 bytes</entry>
- <entry>autoincrementing integer</entry>
+ <entry>large autoincrementing integer</entry>
<entry>1 to 9223372036854775807</entry>
</row>
</tbody>
</tgroup>
</table>
- </para>
<para>
The syntax of constants for the numeric types is described in
<type>int</type>) and <type>smallint</type>. The type
<type>bigint</type>, and the type names <type>int2</type>,
<type>int4</type>, and <type>int8</type> are extensions, which
- are shared with various other RDBMS products.
+ are shared with various other SQL database systems.
</para>
<note>
values to any particular scale, whereas <type>numeric</type> columns
with a declared scale will coerce input values to that scale.
(The SQL standard requires a default scale of 0, i.e., coercion to
- integer accuracy. We find this a bit useless. If you're concerned about
+ integer precision. We find this a bit useless. If you're concerned about
portability, always specify the precision and scale explicitly.)
</para>
<para>
The data types <type>real</type> and <type>double
precision</type> are inexact, variable-precision numeric types.
- In practice, these types are usually implementations of <acronym>IEEE</acronym> 754
- binary floating point (single and double precision,
- respectively), to the extent that the underlying processor,
- operating system, and compiler support it.
+ In practice, these types are usually implementations of
+ <acronym>IEEE</acronym> Standard 754 for Binary Floating-Point
+ Arithmetic (single and double precision, respectively), to the
+ extent that the underlying processor, operating system, and
+ compiler support it.
</para>
<para>
Thus, we have created an integer column and arranged for its default
values to be assigned from a sequence generator. A <literal>NOT NULL</>
- constraint is applied to ensure that a NULL value cannot be explicitly
+ constraint is applied to ensure that a null value cannot be explicitly
inserted, either. In most cases you would also want to attach a
<literal>UNIQUE</> or <literal>PRIMARY KEY</> constraint to prevent
duplicate values from being inserted by accident, but this is
<title>Monetary Type</title>
<note>
- <title>Deprecated</title>
+ <title>Note</title>
<para>
The <type>money</type> type is deprecated. Use
<type>numeric</type> or <type>decimal</type> instead, in
<para>
The <type>money</type> type stores a currency amount with fixed
- decimal point representation. The output format is
+ decimal point representation; see <xref
+ linkend="datatype-money-table">. The output format is
locale-specific.
</para>
Output is in the latter form.
</para>
- <para>
- <table tocentry="1">
+ <table id="datatype-money-table">
<title>Monetary Types</title>
<tgroup cols="4">
<thead>
<row>
<entry>money</entry>
<entry>4 bytes</entry>
- <entry>Fixed-precision</entry>
+ <entry>currency amount</entry>
<entry>-21474836.48 to +21474836.47</entry>
</row>
</tbody>
</tgroup>
</table>
- </para>
</sect1>
<see>character strings</see>
</indexterm>
- <table tocentry="1">
+ <table id="datatype-character-table">
<title>Character Types</title>
<tgroup cols="2">
<thead>
<tbody>
<row>
<entry><type>character(<replaceable>n</>)</type>, <type>char(<replaceable>n</>)</type></entry>
- <entry>Fixed-length blank padded</entry>
+ <entry>fixed-length, blank padded</entry>
</row>
<row>
<entry><type>character varying(<replaceable>n</>)</type>, <type>varchar(<replaceable>n</>)</type></entry>
- <entry>Variable-length with limit</entry>
+ <entry>variable-length with limit</entry>
</row>
<row>
<entry><type>text</type></entry>
- <entry>Variable unlimited length</entry>
+ <entry>variable unlimited length</entry>
</row>
</tbody>
</tgroup>
</table>
+ <para>
+ <xref linkend="datatype-character-table"> shows the
+ general-purpose character types available in PostgreSQL.
+ </para>
+
<para>
<acronym>SQL</acronym> defines two primary character types:
<type>character(<replaceable>n</>)</type> and <type>character
<para>
There are two other fixed-length character types in
- <productname>PostgreSQL</productname>. The <type>name</type> type
+ <productname>PostgreSQL</productname>, shown in <xref linkend="datatype-character-special-table">.
+ The <type>name</type> type
exists <emphasis>only</emphasis> for storage of internal catalog
names and is not intended for use by the general user. Its length
is currently defined as 64 bytes (63 usable characters plus terminator)
enumeration type.
</para>
- <table tocentry="1">
+ <table id="datatype-character-special-table">
<title>Specialty Character Types</title>
<tgroup cols="3">
<thead>
</thead>
<tbody>
<row>
- <entry>"char"</entry>
+ <entry><type>"char"</type></entry>
<entry>1 byte</entry>
- <entry>Single character internal type</entry>
+ <entry>single character internal type</entry>
</row>
<row>
- <entry>name</entry>
+ <entry><type>name</type></entry>
<entry>64 bytes</entry>
- <entry>Sixty-three character internal type</entry>
+ <entry>sixty-three character internal type</entry>
</row>
</tbody>
</tgroup>
<sect1 id="datatype-binary">
<title>Binary Strings</title>
<para>
- The <type>bytea</type> data type allows storage of binary strings.
+ The <type>bytea</type> data type allows storage of binary strings;
+ see <xref linkend="datatype-binary-table">.
</para>
- <table tocentry="1">
+ <table id="datatype-binary-table">
<title>Binary String Types</title>
<tgroup cols="3">
<thead>
</table>
<para>
- A binary string is a sequence of octets that does not have either a
- character set or collation associated with it. <type>Bytea</type>
- specifically allows storing octets of zero value and other
- <quote>non-printable</quote> octets.
+ A binary string is a sequence of octets (or bytes). Binary
+ strings are distinguished from characters strings by two
+ characteristics: First, binary strings specifically allow storing
+ octets of zero value and other <quote>non-printable</quote>
+ octets. Second, operations on binary strings process the actual
+ bytes, whereas the encoding and processing of character strings
+ depends on locale settings.
</para>
<para>
- Octets of certain values <emphasis>must</emphasis> be escaped (but all
- octet values <emphasis>may</emphasis> be escaped) when used as part of
- a string literal in an <acronym>SQL</acronym> statement. In general,
- to escape an octet, it is converted into the three-digit octal number
+ When entering <type>bytea</type> values, octets of certain values
+ <emphasis>must</emphasis> be escaped (but all octet values
+ <emphasis>may</emphasis> be escaped) when used as part of a string
+ literal in an <acronym>SQL</acronym> statement. In general, to
+ escape an octet, it is converted into the three-digit octal number
equivalent of its decimal octet value, and preceded by two
backslashes. Some octet values have alternate escape sequences, as
shown in <xref linkend="datatype-binary-sqlesc">.
</para>
<table id="datatype-binary-sqlesc">
- <title><acronym>SQL</acronym> Literal Escaped Octets</title>
+ <title><type>bytea</> Literal Escaped Octets</title>
<tgroup cols="5">
<thead>
<row>
<tbody>
<row>
- <entry> <literal> 0 </literal> </entry>
- <entry> zero octet </entry>
- <entry> <literal> '\\000' </literal> </entry>
- <entry> <literal> select '\\000'::bytea; </literal> </entry>
- <entry> <literal> \000 </literal></entry>
+ <entry>0</entry>
+ <entry>zero octet</entry>
+ <entry><literal>'\\000'</literal></entry>
+ <entry><literal>SELECT '\\000'::bytea;</literal></entry>
+ <entry><literal>\000</literal></entry>
</row>
<row>
- <entry> <literal> 39 </literal> </entry>
- <entry> single quote </entry>
- <entry> <literal> '\'' or '\\047' </literal> </entry>
- <entry> <literal> select '\''::bytea; </literal></entry>
- <entry> <literal> ' </literal></entry>
+ <entry>39</entry>
+ <entry>single quote</entry>
+ <entry><literal>'\''</literal> or <literal>'\\047'</literal></entry>
+ <entry><literal>SELECT '\''::bytea;</literal></entry>
+ <entry><literal>'</literal></entry>
</row>
<row>
- <entry> <literal>92</literal> </entry>
- <entry> backslash </entry>
- <entry> <literal> '\\\\' or '\\134' </literal> </entry>
- <entry> <literal> select '\\\\'::bytea; </literal></entry>
- <entry> <literal> \\ </literal></entry>
+ <entry>92</entry>
+ <entry>backslash</entry>
+ <entry><literal>'\\\\'</literal> or <literal>'\\134'</literal></entry>
+ <entry><literal>SELECT '\\\\'::bytea;</literal></entry>
+ <entry><literal>\\</literal></entry>
</row>
</tbody>
</table>
<para>
- Note that the result in each of the examples above was exactly one
+ Note that the result in each of the examples in <xref linkend="datatype-binary-sqlesc"> was exactly one
octet in length, even though the output representation of the zero
octet and backslash are more than one character. <type>Bytea</type>
output octets are also escaped. In general, each
</para>
<table id="datatype-binary-resesc">
- <title><acronym>SQL</acronym> Output Escaped Octets</title>
+ <title><type>bytea</> Output Escaped Octets</title>
<tgroup cols="5">
<thead>
<row>
<tbody>
<row>
- <entry> <literal> 92 </literal> </entry>
- <entry> backslash </entry>
- <entry> <literal> \\ </literal> </entry>
- <entry> <literal> select '\\134'::bytea; </literal></entry>
- <entry> <literal> \\ </literal></entry>
+ <entry>92</entry>
+ <entry>backslash</entry>
+ <entry><literal>\\</literal></entry>
+ <entry><literal>SELECT '\\134'::bytea;</literal></entry>
+ <entry><literal>\\</literal></entry>
</row>
<row>
- <entry> <literal> 0 to 31 and 127 to 255 </literal> </entry>
- <entry> <quote>non-printable</quote> octets </entry>
- <entry> <literal> \### (octal value) </literal> </entry>
- <entry> <literal> select '\\001'::bytea; </literal> </entry>
- <entry> <literal> \001 </literal></entry>
+ <entry>0 to 31 and 127 to 255</entry>
+ <entry><quote>non-printable</quote> octets</entry>
+ <entry><literal>\### (octal value)</literal></entry>
+ <entry><literal>SELECT '\\001'::bytea;</literal></entry>
+ <entry><literal>\001</literal></entry>
</row>
<row>
- <entry> <literal> 32 to 126 </literal> </entry>
- <entry> <quote>printable</quote> octets </entry>
- <entry> ASCII representation </entry>
- <entry> <literal> select '\\176'::bytea; </literal> </entry>
- <entry> <literal> ~ </literal></entry>
+ <entry>32 to 126</entry>
+ <entry><quote>printable</quote> octets</entry>
+ <entry>ASCII representation</entry>
+ <entry><literal>SELECT '\\176'::bytea;</literal></entry>
+ <entry><literal>~</literal></entry>
</row>
</tbody>
</table>
<para>
- <acronym>SQL</acronym> string literals (input strings) must be
- preceded with two backslashes due to the fact that they must pass
- through two parsers in the PostgreSQL backend. The first backslash
- is interpreted as an escape character by the string-literal parser,
- and therefore is consumed, leaving the octets that follow.
- The remaining backslash is recognized by the <type>bytea</type> input
- function as the prefix of a three digit octal value. For example, a string
- literal passed to the backend as <literal>'\\001'</literal> becomes
+ To use the <type>bytea</type> escaped octet notation, string
+ literals (input strings) must contain two backslashes due because
+ they must pass through two parsers in the PostgreSQL server. The
+ first backslash is interpreted as an escape character by the
+ string-literal parser, and therefore is consumed, leaving the
+ characters that follow. The remaining backslash is recognized by
+ the <type>bytea</type> input function as the prefix of a three
+ digit octal value. For example, a string literal passed to the
+ backend as <literal>'\\001'</literal> becomes
<literal>'\001'</literal> after passing through the string-literal
parser. The <literal>'\001'</literal> is then sent to the
- <type>bytea</type> input function, where it is converted to a single
- octet with a decimal value of 1.
+ <type>bytea</type> input function, where it is converted to a
+ single octet with a decimal value of 1.
</para>
<para>
backslashes in the string passed to the <type>bytea</type> input function,
which interprets them as representing a single backslash.
For example, a string literal passed to the
- backend as <literal>'\\\\'</literal> becomes <literal>'\\'</literal>
+ server as <literal>'\\\\'</literal> becomes <literal>'\\'</literal>
after passing through the string-literal parser. The
<literal>'\\'</literal> is then sent to the <type>bytea</type> input
function, where it is converted to a single octet with a decimal
escape character.
</para>
- <para>
- <type>Bytea</type> provides most of the functionality of the binary
- string type per SQL99 section 4.3. A comparison of SQL99 Binary
- Strings and PostgreSQL <type>bytea</type> is presented in
- <xref linkend="datatype-binary-compat-comp">.
- </para>
-
- <table id="datatype-binary-compat-comp">
- <title>Comparison of SQL99 Binary String and PostgreSQL
- <type>BYTEA</type> types</title>
- <tgroup cols="2">
- <thead>
- <row>
- <entry>SQL99</entry>
- <entry><type>BYTEA</type></entry>
- </row>
- </thead>
-
- <tbody>
- <row>
- <entry> Name of data type <type>BINARY LARGE OBJECT</type>
- or <type>BLOB</type> </entry>
- <entry> Name of data type <type>BYTEA</type> </entry>
- </row>
-
- <row>
- <entry> Sequence of octets that does not have either a character set
- or collation associated with it. </entry>
- <entry> same </entry>
- </row>
-
- <row>
- <entry> Described by a binary data type descriptor containing the
- name of the data type and the maximum length
- in octets</entry>
- <entry> Described by a binary data type descriptor containing the
- name of the data type with no specific maximum length
- </entry>
- </row>
-
- <row>
- <entry> All binary strings are mutually comparable in accordance
- with the rules of comparison predicates.</entry>
- <entry> same</entry>
- </row>
-
- <row>
- <entry> Binary string values can only be compared for equality.
- </entry>
- <entry> Binary string values can be compared for equality, greater
- than, greater than or equal, less than, less than or equal
- </entry>
- </row>
-
- <row>
- <entry> Operators operating on and returning binary strings
- include concatenation, substring, overlay, and trim</entry>
- <entry> Operators operating on and returning binary strings
- include concatenation, substring, and trim. The
- <literal>leading</literal> and <literal>trailing</literal>
- arguments for trim are not yet implemented.
- </entry>
- </row>
-
- <row>
- <entry> Other operators involving binary strings
- include length, position, and the like predicate</entry>
- <entry> same</entry>
- </row>
-
- <row>
- <entry> A binary string literal is comprised of an even number of
- hexadecimal digits, in single quotes, preceded by <quote>X</quote>,
- e.g. <literal>X'1a43fe'</literal></entry>
- <entry> A binary string literal is comprised of octets
- escaped according to the rules shown in
- <xref linkend="datatype-binary-sqlesc"> </entry>
- </row>
- </tbody>
- </tgroup>
- </table>
- </sect1>
+ <para>
+ The SQL standard defines a different binary string type, called
+ <type>BLOB</type> or <type>BINARY LARGE OBJECT</type>. The input
+ format is different compared to <type>bytea</type>, but the
+ provided functions and operators are mostly the same.
+ </para>
+ </sect1>
<sect1 id="datatype-datetime">
<para>
<productname>PostgreSQL</productname> supports the full set of
- <acronym>SQL</acronym> date and time types.
+ <acronym>SQL</acronym> date and time types, shown in <xref
+ linkend="datatype-datetime-table">.
</para>
- <para>
- <table tocentry="1">
+ <table id="datatype-datetime-table">
<title>Date/Time Types</title>
<tgroup cols="6">
<thead>
</tbody>
</tgroup>
</table>
- </para>
<para>
- <type>time</type>, <type>timestamp</type>, and <type>interval</type>
- accept an
- optional precision value <replaceable>p</replaceable> which
- specifies the number of fractional digits retained in the seconds
- field. By default, there is no explicit bound on precision. The
- allowed range of <replaceable>p</replaceable> is from 0 to 6.
+ <type>time</type>, <type>timestamp</type>, and
+ <type>interval</type> accept an optional precision value
+ <replaceable>p</replaceable> which specifies the number of
+ fractional digits retained in the seconds field. By default, there
+ is no explicit bound on precision. The allowed range of
+ <replaceable>p</replaceable> is from 0 to 6 for the
+ <type>timestamp</type> and <type>interval</type> types, 0 to 13
+ for the <type>time</type> types.
</para>
<note>
<para>
- When timestamps are stored as double precision floating-point
+ When <type>timestamp</> values are stored as double precision floating-point
numbers (currently the default), the effective limit of precision
may be less than 6, since timestamp values are stored as seconds
since 2000-01-01. Microsecond precision is achieved for dates within
outside that range are in <acronym>UTC</acronym>.
</para>
+ <para>
+ The type <type>time with time zone</type> is defined by the SQL
+ standard, but the definition exhibits properties which lead to
+ questionable usefulness. In most cases, a combination of
+ <type>date</type>, <type>time</type>, <type>timestamp without time
+ zone</type> and <type>timestamp with time zone</type> should
+ provide a complete range of date/time functionality required by
+ any application.
+ </para>
+
<para>
The types <type>abstime</type>
and <type>reltime</type> are lower precision types which are used internally.
or <literal>SET DateStyle TO 'NonEuropean'</literal>
specifies the variant <quote>month before day</quote>, the command
<literal>SET DateStyle TO 'European'</literal> sets the variant
- <quote>day before month</quote>. The <literal>ISO</literal> style
- is the default but this default can be changed at compile time or at run time.
+ <quote>day before month</quote>.
</para>
<para>
in single quotes, like text strings. Refer to
<xref linkend="sql-syntax-constants-generic"> for more
information.
- <acronym>SQL9x</acronym> requires the following syntax
+ <acronym>SQL</acronym> requires the following syntax
<synopsis>
<replaceable>type</replaceable> [ (<replaceable>p</replaceable>) ] '<replaceable>value</replaceable>'
</synopsis>
</para>
<sect3>
- <title><type>date</type></title>
+ <title>Dates</title>
<indexterm>
<primary>date</primary>
</indexterm>
<para>
- The following are some possible inputs for the <type>date</type> type.
+ <xref linkend="datatype-datetime-date-table"> shows some possible
+ inputs for the <type>date</type> type.
+ </para>
- <table tocentry="1">
+ <table id="datatype-datetime-date-table">
<title>Date Input</title>
<tgroup cols="2">
<thead>
<tbody>
<row>
<entry>January 8, 1999</entry>
- <entry>Unambiguous</entry>
+ <entry>unambiguous</entry>
</row>
<row>
<entry>1999-01-08</entry>
</row>
<row>
<entry>1999.008</entry>
- <entry>Year and day of year</entry>
+ <entry>year and day of year</entry>
</row>
<row>
<entry>99008</entry>
- <entry>Year and day of year</entry>
+ <entry>year and day of year</entry>
</row>
<row>
<entry>J2451187</entry>
</row>
<row>
<entry>January 8, 99 BC</entry>
- <entry>Year 99 before the Common Era</entry>
+ <entry>year 99 before the Common Era</entry>
</row>
</tbody>
</tgroup>
</table>
- </para>
</sect3>
<sect3>
- <title><type>time [ ( <replaceable>p</replaceable> ) ] [ without time zone ]</type></title>
+ <title>Times</title>
<indexterm>
<primary>time</primary>
<primary>time without time zone</primary>
<secondary>time</secondary>
</indexterm>
+ <indexterm>
+ <primary>time with time zone</primary>
+ <secondary>data type</secondary>
+ </indexterm>
<para>
- Per SQL99, this type can be specified as <type>time</type> or
+ The <type>time</type> type can be specified as <type>time</type> or
as <type>time without time zone</type>. The optional precision
<replaceable>p</replaceable> should be between 0 and 13, and
defaults to the precision of the input time literal.
</para>
<para>
- The following are valid <type>time</type> inputs.
+ <xref linkend="datatype-datetime-time-table"> shows the valid <type>time</type> inputs.
+ </para>
- <table tocentry="1">
+ <table id="datatype-datetime-time-table">
<title>Time Input</title>
<tgroup cols="2">
<thead>
</row>
<row>
<entry><literal>04:05 AM</literal></entry>
- <entry>Same as 04:05; AM does not affect value</entry>
+ <entry>same as 04:05; AM does not affect value</entry>
</row>
<row>
<entry><literal>04:05 PM</literal></entry>
- <entry>Same as 16:05; input hour must be <= 12</entry>
+ <entry>same as 16:05; input hour must be <= 12</entry>
</row>
<row>
<entry><literal>allballs</literal></entry>
- <entry>Same as 00:00:00</entry>
+ <entry>same as 00:00:00</entry>
</row>
</tbody>
</tgroup>
</table>
- </para>
- </sect3>
-
- <sect3>
- <title><type>time [ ( <replaceable>precision</replaceable> ) ] with time zone</type></title>
-
- <indexterm>
- <primary>time with time zone</primary>
- <secondary>data type</secondary>
- </indexterm>
- <indexterm>
- <primary>time</primary>
- <secondary>data type</secondary>
- </indexterm>
-
- <para>
- This type is defined by SQL92, but the definition exhibits
- properties which lead to questionable usefulness. In
- most cases, a combination of <type>date</type>,
- <type>time</type>, <type>timestamp without time zone</type>
- and <type>timestamp with time zone</type>
- should provide a complete range of date/time functionality
- required by any application.
- </para>
<para>
- The optional precision
- <replaceable>p</replaceable> should be between 0 and 13, and
- defaults to the precision of the input time literal.
+ The type <type>time with time zone</type> accepts all input also
+ legal for the <type>time</type> type, appended with a legal time
+ zone, as shown in <xref
+ linkend="datatype-datetime-timetz-table">.
</para>
- <para>
- <type>time with time zone</type> accepts all input also legal
- for the <type>time</type> type, appended with a legal time zone,
- as follows:
-
- <table tocentry="1">
+ <table id="datatype-datetime-timetz-table">
<title>Time With Time Zone Input</title>
<tgroup cols="2">
<thead>
</tbody>
</tgroup>
</table>
- </para>
<para>
Refer to <xref linkend="datatype-timezone-table"> for
</sect3>
<sect3>
- <title><type>timestamp [ (<replaceable>precision</replaceable>) ] without time zone</type></title>
+ <title>Time stamps</title>
+
+ <indexterm>
+ <primary>timestamp</primary>
+ <secondary>data type</secondary>
+ </indexterm>
<indexterm>
<primary>timestamp without time zone</primary>
</indexterm>
<para>
- Valid input for the <type>timestamp [ (<replaceable>p</replaceable>) ] without time zone</type>
- type consists of a concatenation
- of a date and a time, followed by an optional <literal>AD</literal> or
- <literal>BC</literal>, followed by an optional time zone. (See below.)
- Thus
+ Time stamp types exist as <type>timestamp [
+ (<replaceable>p</replaceable>) ]</type>, <type>timestamp [
+ (<replaceable>p</replaceable>) ] without time zone</type> and
+ <type>timestamp [ (<replaceable>p</replaceable>) ] without time
+ zone</type>. A plain <type>timestamp</type> is equivalent to
+ <type>timestamp without timezone</type>.
+ </para>
+
+ <para>
+ Valid input for the time stamp types consists of a concatenation
+ of a date and a time, followed by an optional
+ <literal>AD</literal> or <literal>BC</literal>, followed by an
+ optional time zone. (See <xref
+ linkend="datatype-timezone-table">.) Thus
<programlisting>
1999-01-08 04:05:06
+</programlisting>
+ and
+<programlisting>
+1999-01-08 04:05:06 -8:00
</programlisting>
- is a valid <type>timestamp without time zone</type> value that
- is <acronym>ISO</acronym>-compliant.
- In addition, the wide-spread format
+ are valid values, which follow the <acronym>ISO</acronym> 8601
+ standard. In addition, the wide-spread format
<programlisting>
January 8 04:05:06 1999 PST
<para>
The optional precision
- <replaceable>p</replaceable> should be between 0 and 13, and
+ <replaceable>p</replaceable> should be between 0 and 6, and
defaults to the precision of the input <type>timestamp</type> literal.
</para>
resulting date/time value is derived from the explicit date/time
fields in the input value, and is not adjusted for time zone.
</para>
- </sect3>
-
- <sect3>
- <title><type>timestamp [ (<replaceable>precision</replaceable>) ] with time zone</type></title>
-
- <indexterm>
- <primary>timestamp</primary>
- <secondary>data type</secondary>
- </indexterm>
-
- <para>
- Valid input for the <type>timestamp</type> type consists of a concatenation
- of a date and a time, followed by an optional <literal>AD</literal> or
- <literal>BC</literal>, followed by an optional time zone. (See below.)
- Thus
-
-<programlisting>
-1999-01-08 04:05:06 -8:00
-</programlisting>
-
- is a valid <type>timestamp</type> value that is <acronym>ISO</acronym>-compliant.
- In addition, the wide-spread format
-
-<programlisting>
-January 8 04:05:06 1999 PST
-</programlisting>
- is supported.
- </para>
-
- <para>
- The optional precision
- <replaceable>p</replaceable> should be between 0 and 13, and
- defaults to the precision of the input <type>timestamp</type> literal.
- </para>
- <para>
<table tocentry="1" id="datatype-timezone-table">
<title>Time Zone Input</title>
<tgroup cols="2">
</tbody>
</tgroup>
</table>
- </para>
</sect3>
<sect3>
- <title><type>interval [ ( <replaceable>precision</replaceable> ) ]</type></title>
+ <title>Intervals</title>
<indexterm>
<primary>interval</primary>
<para>
The optional precision
- <replaceable>p</replaceable> should be between 0 and 13, and
+ <replaceable>p</replaceable> should be between 0 and 6, and
defaults to the precision of the input literal.
</para>
</sect3>
input for the corresponding data type: <literal>CURRENT_DATE</literal>,
<literal>CURRENT_TIME</literal>,
<literal>CURRENT_TIMESTAMP</literal>. The latter two accept an
- optional precision specification.
+ optional precision specification. (See also <xref linkend="functions-datetime">.)
</para>
<para>
<productname>PostgreSQL</productname> also supports several
- special constants for convenience.
+ special constants for convenience, shown in <xref
+ linkend="datatype-datetime-special-table">.
+ </para>
- <table tocentry="1">
+ <table id="datatype-datetime-special-table">
<title>Special Date/Time Constants</title>
<tgroup cols="2">
<thead>
</row>
<row>
<entry><literal>infinity</literal></entry>
- <entry>Later than other valid times</entry>
+ <entry>later than other valid times</entry>
</row>
<row>
<entry><literal>-infinity</literal></entry>
- <entry>Earlier than other valid times</entry>
+ <entry>earlier than other valid times</entry>
</row>
<row>
<entry><literal>invalid</literal></entry>
- <entry>Illegal entry</entry>
+ <entry>illegal entry</entry>
</row>
<row>
<entry><literal>now</literal></entry>
- <entry>Current transaction time</entry>
+ <entry>current transaction time</entry>
</row>
<row>
<entry><literal>today</literal></entry>
- <entry>Midnight today</entry>
+ <entry>midnight today</entry>
</row>
<row>
<entry><literal>tomorrow</literal></entry>
- <entry>Midnight tomorrow</entry>
+ <entry>midnight tomorrow</entry>
</row>
<row>
<entry><literal>yesterday</literal></entry>
- <entry>Midnight yesterday</entry>
+ <entry>midnight yesterday</entry>
</row>
<row>
<entry><literal>zulu</>, <literal>allballs</>, <literal>z</></entry>
</tgroup>
</table>
- <literal>'now'</literal> is
- evaluated when the value is first interpreted.
- </para>
-
- <note>
- <para>
- As of <productname>PostgreSQL</> version 7.2,
- <literal>'current'</literal> is no longer supported as a
- date/time constant.
- Previously,
- <literal>'current'</literal> was stored as a special value,
- and evaluated to <literal>'now'</literal> only when
- used in an expression or type
- conversion.
- </para>
- </note>
</sect3>
</sect2>
</indexterm>
<para>
- Output formats can be set to one of the four styles
- ISO 8601, <acronym>SQL</acronym> (Ingres), traditional
- PostgreSQL, and German, using the <command>SET DateStyle</command>.
- The default is the <acronym>ISO</acronym> format.
+ Output formats can be set to one of the four styles ISO 8601,
+ <acronym>SQL</acronym> (Ingres), traditional PostgreSQL, and
+ German, using the <command>SET DateStyle</command>. The default
+ is the <acronym>ISO</acronym> format. (The SQL standard requires
+ the use of the ISO 8601 format. The name of the
+ <quote>SQL</quote> output format is a historical accident.)
+ <xref linkend="datatype-datetime-output-table"> shows examples of
+ each output style. The output of the <type>date</type> and
+ <type>time</type> types is of course only the date or time part
+ in accordance with the given examples.
+ </para>
- <table tocentry="1">
+ <table id="datatype-datetime-output-table">
<title>Date/Time Output Styles</title>
<tgroup cols="3">
<thead>
</thead>
<tbody>
<row>
- <entry>'ISO'</entry>
- <entry>ISO-8601 standard</entry>
+ <entry>ISO</entry>
+ <entry>ISO 8601/SQL standard</entry>
<entry>1997-12-17 07:37:16-08</entry>
</row>
<row>
- <entry>'SQL'</entry>
- <entry>Traditional style</entry>
+ <entry>SQL</entry>
+ <entry>traditional style</entry>
<entry>12/17/1997 07:37:16.00 PST</entry>
</row>
<row>
- <entry>'PostgreSQL'</entry>
- <entry>Original style</entry>
+ <entry>PostgreSQL</entry>
+ <entry>original style</entry>
<entry>Wed Dec 17 07:37:16 1997 PST</entry>
</row>
<row>
- <entry>'German'</entry>
- <entry>Regional style</entry>
+ <entry>German</entry>
+ <entry>regional style</entry>
<entry>17.12.1997 07:37:16.00 PST</entry>
</row>
</tbody>
</tgroup>
</table>
- </para>
<para>
- The output of the <type>date</type> and <type>time</type> styles
- is of course
- only the date or time part in accordance with the above examples.
+ The <acronym>SQL</acronym> style has European and non-European
+ (U.S.) variants, which determines whether month follows day or
+ vice versa. (See <xref linkend="datatype-datetime-input">
+ for how this setting also affects interpretation of input values.)
+ <xref linkend="datatype-datetime-output2-table"> shows an
+ example.
</para>
- <para>
- The <acronym>SQL</acronym> style has European and non-European
- (U.S.) variants,
- which determines whether month follows day or vice versa. (See
- also <xref linkend="datatype-datetime-input">
- for how this setting affects interpretation of
- input values.)
-
- <table tocentry="1">
- <title>Date-Order Conventions</title>
+ <table id="datatype-datetime-output2-table">
+ <title>Date Order Conventions</title>
<tgroup cols="3">
<thead>
<row>
</tbody>
</tgroup>
</table>
- </para>
<para>
<type>interval</type> output looks like the input format, except that units like
</para>
<para>
- There are several ways to affect the appearance of date/time types:
-
- <itemizedlist spacing="compact" mark="bullet">
- <listitem>
- <para>
- The <envar>PGDATESTYLE</envar> environment variable used by the backend directly
- on postmaster start-up.
- </para>
- </listitem>
- <listitem>
- <para>
- The <envar>PGDATESTYLE</envar> environment variable used by the frontend <application>libpq</application>
- on session start-up.
- </para>
- </listitem>
- <listitem>
- <para>
- <command>SET DATESTYLE</command> <acronym>SQL</acronym> command.
- </para>
- </listitem>
- </itemizedlist>
+ The date/time styles can be selected by the user using the
+ <command>SET DATESTYLE</command> command, the
+ <varname>datestyle</varname> parameter in the
+ <filename>postgresql.conf</filename> configuration file, and the
+ <envar>PGDATESTYLE</envar> environment variable on the server or
+ client. The formatting function <function>to_char</function>
+ (see <xref linkend="functions-formatting">) is also available as
+ a more flexible way to format the date/time output.
</para>
-
</sect2>
<sect2 id="datatype-timezones">
<para>
<productname>PostgreSQL</productname> endeavors to be compatible with
- <acronym>SQL92</acronym> definitions for typical usage.
- However, the <acronym>SQL92</acronym> standard has an odd mix of date and
+ the <acronym>SQL</acronym> standard definitions for typical usage.
+ However, the <acronym>SQL</acronym> standard has an odd mix of date and
time types and capabilities. Two obvious problems are:
<itemizedlist>
<para>
To address these difficulties, we recommend using date/time
types that contain both date and time when using time zones. We
- recommend <emphasis>not</emphasis> using the SQL92 type <type>time
+ recommend <emphasis>not</emphasis> using the type <type>time
with time zone</type> (though it is supported by
<productname>PostgreSQL</productname> for legacy applications and
- for compatibility with other RDBMS implementations).
+ for compatibility with other SQL implementations).
<productname>PostgreSQL</productname>
assumes your local time zone for any type containing only
date or time. Further, time zone support is derived from
<para>
There are several ways to affect the time-zone behavior:
- <itemizedlist spacing="compact" mark="bullet">
+ <itemizedlist>
<listitem>
<para>
- The <envar>TZ</envar> environment variable is used by the backend directly
- on postmaster start-up as the default time zone.
+ The <envar>TZ</envar> environment variable on the server host
+ is used by the server as the default time zone.
</para>
</listitem>
+
<listitem>
<para>
- The <envar>PGTZ</envar> environment variable, if set at the client, is used by <application>libpq</application>
- to send a <command>SET TIME ZONE</command> command to the backend upon
- connection.
+ The <envar>PGTZ</envar> environment variable, if set at the
+ client, is used by <application>libpq</application>
+ applications to send a <command>SET TIME ZONE</command>
+ command to the server upon connection.
</para>
</listitem>
+
<listitem>
<para>
The <acronym>SQL</acronym> command <command>SET TIME ZONE</command>
sets the time zone for the session.
</para>
</listitem>
+
<listitem>
<para>
- The <acronym>SQL92</acronym> qualifier on
+ The construct
<programlisting>
<replaceable>timestamp</replaceable> AT TIME ZONE '<replaceable>zone</replaceable>'
</programlisting>
where <replaceable>zone</replaceable> can be specified as a
- text time zone (e.g. <literal>'PST'</literal>) or as an
- interval (e.g. <literal>INTERVAL '-08:00'</literal>).
+ text time zone (e.g., <literal>'PST'</literal>) or as an
+ interval (e.g., <literal>INTERVAL '-08:00'</literal>).
</para>
</listitem>
</itemizedlist>
</para>
</note>
- <note>
- <para>
- If the run-time option <literal>AUSTRALIAN_TIMEZONES</literal> is set
- then <literal>CST</literal> and <literal>EST</literal> refer to
- Australian time zones, not American ones.
- </para>
- </note>
+ <para>
+ Refer to <xref linkend="datetime-appendix"> for a list of
+ available time zones.
+ </para>
</sect2>
<para>
<productname>PostgreSQL</productname> uses Julian dates
for all date/time calculations. They have the nice property of correctly
- predicting/calculating any date more recent than 4713BC
+ predicting/calculating any date more recent than 4713 BC
to far into the future, using the assumption that the length of the
year is 365.2425 days.
</para>
<para>
<productname>PostgreSQL</productname> provides the
- <acronym>SQL99</acronym> type <type>boolean</type>.
+ standard <acronym>SQL</acronym> type <type>boolean</type>.
<type>boolean</type> can have one of only two states:
<quote>true</quote> or <quote>false</quote>. A third state,
<quote>unknown</quote>, is represented by the
- <acronym>SQL</acronym> NULL state.
+ <acronym>SQL</acronym> null value.
</para>
<para>
<title>Geometric Types</title>
<para>
- Geometric types represent two-dimensional spatial objects.
- The most fundamental type,
- the point, forms the basis for all of the other types.
+ Geometric data types represent two-dimensional spatial
+ objects. <xref linkend="datatype-geo-table"> shows the geometric
+ types available in PostgreSQL. The most fundamental type, the
+ point, forms the basis for all of the other types.
</para>
- <para>
- <table tocentry="1">
+ <table id="datatype-geo-table">
<title>Geometric Types</title>
<tgroup cols="4">
<thead>
</tbody>
</tgroup>
</table>
- </para>
<para>
A rich set of functions and operators is available to perform various geometric
operations such as scaling, translation, rotation, and determining
- intersections.
+ intersections. They are explained in <xref linkend="functions-geometry">.
</para>
<sect2>
<para>
Points are the fundamental two-dimensional building block for geometric types.
- </para>
-
- <para>
<type>point</type> is specified using the following syntax:
- <synopsis>
+<synopsis>
( <replaceable>x</replaceable> , <replaceable>y</replaceable> )
<replaceable>x</replaceable> , <replaceable>y</replaceable>
- </synopsis>
+</synopsis>
where the arguments are
<term><replaceable>x</replaceable></term>
<listitem>
<para>
- The x-axis coordinate as a floating-point number
+ the x-axis coordinate as a floating-point number
</para>
</listitem>
</varlistentry>
<term><replaceable>y</replaceable></term>
<listitem>
<para>
- The y-axis coordinate as a floating-point number
+ the y-axis coordinate as a floating-point number
</para>
</listitem>
</varlistentry>
<para>
Line segments (<type>lseg</type>) are represented by pairs of points.
- </para>
-
- <para>
<type>lseg</type> is specified using the following syntax:
- <synopsis>
+<synopsis>
( ( <replaceable>x1</replaceable> , <replaceable>y1</replaceable> ) , ( <replaceable>x2</replaceable> , <replaceable>y2</replaceable> ) )
( <replaceable>x1</replaceable> , <replaceable>y1</replaceable> ) , ( <replaceable>x2</replaceable> , <replaceable>y2</replaceable> )
<replaceable>x1</replaceable> , <replaceable>y1</replaceable> , <replaceable>x2</replaceable> , <replaceable>y2</replaceable>
- </synopsis>
+</synopsis>
where the arguments are
<term>(<replaceable>x2</replaceable>,<replaceable>y2</replaceable>)</term>
<listitem>
<para>
- The end points of the line segment
+ the end points of the line segment
</para>
</listitem>
</varlistentry>
<para>
Boxes are represented by pairs of points that are opposite
corners of the box.
- </para>
-
- <para>
<type>box</type> is specified using the following syntax:
- <synopsis>
+<synopsis>
( ( <replaceable>x1</replaceable> , <replaceable>y1</replaceable> ) , ( <replaceable>x2</replaceable> , <replaceable>y2</replaceable> ) )
( <replaceable>x1</replaceable> , <replaceable>y1</replaceable> ) , ( <replaceable>x2</replaceable> , <replaceable>y2</replaceable> )
<replaceable>x1</replaceable> , <replaceable>y1</replaceable> , <replaceable>x2</replaceable> , <replaceable>y2</replaceable>
- </synopsis>
+</synopsis>
where the arguments are
<term>(<replaceable>x2</replaceable>,<replaceable>y2</replaceable>)</term>
<listitem>
<para>
- Opposite corners of the box
+ opposite corners of the box
</para>
</listitem>
</varlistentry>
The corners are reordered on input to store
the upper right corner, then the lower left corner.
Other corners of the box can be entered, but the lower
- left and upper right corners are determined from the input and stored.
+ left and upper right corners are determined from the input and stored corners.
</para>
</sect2>
<para>
<type>path</type> is specified using the following syntax:
- <synopsis>
+<synopsis>
( ( <replaceable>x1</replaceable> , <replaceable>y1</replaceable> ) , ... , ( <replaceable>xn</replaceable> , <replaceable>yn</replaceable> ) )
[ ( <replaceable>x1</replaceable> , <replaceable>y1</replaceable> ) , ... , ( <replaceable>xn</replaceable> , <replaceable>yn</replaceable> ) ]
( <replaceable>x1</replaceable> , <replaceable>y1</replaceable> ) , ... , ( <replaceable>xn</replaceable> , <replaceable>yn</replaceable> )
( <replaceable>x1</replaceable> , <replaceable>y1</replaceable> , ... , <replaceable>xn</replaceable> , <replaceable>yn</replaceable> )
<replaceable>x1</replaceable> , <replaceable>y1</replaceable> , ... , <replaceable>xn</replaceable> , <replaceable>yn</replaceable>
- </synopsis>
+</synopsis>
where the arguments are
<listitem>
<para>
End points of the line segments comprising the path.
- A leading square bracket ("[") indicates an open path, while
- a leading parenthesis ("(") indicates a closed path.
+ A leading square bracket (<literal>[</>) indicates an open path, while
+ a leading parenthesis (<literal>(</>) indicates a closed path.
</para>
</listitem>
</varlistentry>
<para>
<type>polygon</type> is specified using the following syntax:
- <synopsis>
+<synopsis>
( ( <replaceable>x1</replaceable> , <replaceable>y1</replaceable> ) , ... , ( <replaceable>xn</replaceable> , <replaceable>yn</replaceable> ) )
( <replaceable>x1</replaceable> , <replaceable>y1</replaceable> ) , ... , ( <replaceable>xn</replaceable> , <replaceable>yn</replaceable> )
( <replaceable>x1</replaceable> , <replaceable>y1</replaceable> , ... , <replaceable>xn</replaceable> , <replaceable>yn</replaceable> )
<replaceable>x1</replaceable> , <replaceable>y1</replaceable> , ... , <replaceable>xn</replaceable> , <replaceable>yn</replaceable>
- </synopsis>
+</synopsis>
where the arguments are
<para>
Circles are represented by a center point and a radius.
- </para>
-
- <para>
<type>circle</type> is specified using the following syntax:
- <synopsis>
+<synopsis>
< ( <replaceable>x</replaceable> , <replaceable>y</replaceable> ) , <replaceable>r</replaceable> >
( ( <replaceable>x</replaceable> , <replaceable>y</replaceable> ) , <replaceable>r</replaceable> )
( <replaceable>x</replaceable> , <replaceable>y</replaceable> ) , <replaceable>r</replaceable>
<replaceable>x</replaceable> , <replaceable>y</replaceable> , <replaceable>r</replaceable>
- </synopsis>
+</synopsis>
where the arguments are
<term>(<replaceable>x</replaceable>,<replaceable>y</replaceable>)</term>
<listitem>
<para>
- Center of the circle
+ center of the circle
</para>
</listitem>
</varlistentry>
<term><replaceable>r</replaceable></term>
<listitem>
<para>
- Radius of the circle
+ radius of the circle
</para>
</listitem>
</varlistentry>
<para>
<productname>PostgreSQL</> offers data types to store IP and MAC
- addresses. It is preferable to use these types over plain text
- types, because these types offer input error checking and several
- specialized operators and functions.
+ addresses, shown in <xref linkend="datatype-net-types-table">. It
+ is preferable to use these types over plain text types, because
+ these types offer input error checking and several specialized
+ operators and functions.
+ </para>
<table tocentry="1" id="datatype-net-types-table">
<title>Network Address Data Types</title>
</tbody>
</tgroup>
</table>
- </para>
<para>
- IP v6 is not yet supported.
+ IPv6 is not yet supported.
</para>
</para>
<para>
- Here are some examples:
+ <xref linkend="datatype-net-cidr-table"> shows some examples.
+ </para>
- <table tocentry="1">
+ <table id="datatype-net-cidr-table">
<title><type>cidr</> Type Input Examples</title>
<tgroup cols="3">
<thead>
</tbody>
</tgroup>
</table>
- </para>
</sect2>
<sect2 id="datatype-inet-vs-cidr">
Type <type>oid</> represents an object identifier. There are also
several aliases for <type>oid</>: <type>regproc</>, <type>regprocedure</>,
<type>regoper</>, <type>regoperator</>, <type>regclass</>,
- and <type>regtype</>.
+ and <type>regtype</>. <xref linkend="datatype-oid-table"> shows an overview.
</para>
<para>
types allow simplified lookup of OID values for objects: for example,
one may write <literal>'mytable'::regclass</> to get the OID of table
<literal>mytable</>, rather than <literal>SELECT oid FROM pg_class WHERE
- relname = 'mytable'</>. (In reality, a much more complicated SELECT would
+ relname = 'mytable'</>. (In reality, a much more complicated <command>SELECT</> would
be needed to deal with selecting the right OID when there are multiple
tables named <literal>mytable</> in different schemas.)
</para>
- <para>
- <table tocentry="1">
+ <table id="datatype-oid-table">
<title>Object Identifier Types</title>
<tgroup cols="4">
<thead>
<entry>Type name</entry>
<entry>References</entry>
<entry>Description</entry>
- <entry>Examples</entry>
+ <entry>Value example</entry>
</row>
</thead>
<row>
<entry><type>oid</></entry>
<entry>any</entry>
- <entry>Numeric object identifier</entry>
- <entry>564182</entry>
+ <entry>numeric object identifier</entry>
+ <entry><literal>564182</></entry>
</row>
<row>
<entry><type>regproc</></entry>
<entry><structname>pg_proc</></entry>
- <entry>Function name</entry>
- <entry>sum</entry>
+ <entry>function name</entry>
+ <entry><literal>sum</></entry>
</row>
<row>
<entry><type>regprocedure</></entry>
<entry><structname>pg_proc</></entry>
- <entry>Function with argument types</entry>
- <entry>sum(int4)</entry>
+ <entry>function with argument types</entry>
+ <entry><literal>sum(int4)</></entry>
</row>
<row>
<entry><type>regoper</></entry>
- <entry>pg_operator</entry>
- <entry>Operator name</entry>
- <entry>+</entry>
+ <entry><structname>pg_operator</></entry>
+ <entry>operator name</entry>
+ <entry><literal>+</></entry>
</row>
<row>
<entry><type>regoperator</></entry>
- <entry>pg_operator</entry>
- <entry>Operator with argument types</entry>
- <entry>*(integer,integer) -(NONE,integer)</entry>
+ <entry><structname>pg_operator</></entry>
+ <entry>operator with argument types</entry>
+ <entry><literal>*(integer,integer)</> or <literal>-(NONE,integer)</></entry>
</row>
<row>
<entry><type>regclass</></entry>
- <entry>pg_class</entry>
- <entry>Relation name</entry>
- <entry>pg_type</entry>
+ <entry><structname>pg_class</></entry>
+ <entry>relation name</entry>
+ <entry><literal>pg_type</></entry>
</row>
<row>
<entry><type>regtype</></entry>
- <entry>pg_type</entry>
- <entry>Type name</entry>
- <entry>integer</entry>
+ <entry><structname>pg_type</></entry>
+ <entry>type name</entry>
+ <entry><literal>integer</></entry>
</row>
</tbody>
</tgroup>
</table>
- </para>
<para>
All of the OID alias types accept schema-qualified names, and will
accept input names that are unique (not overloaded), so they are
of limited use; for most uses <type>regprocedure</> or
<type>regoperator</> is more appropriate. For <type>regoperator</>,
- unary operators are identified by writing NONE for the unused
+ unary operators are identified by writing <literal>NONE</> for the unused
operand.
</para>
Transaction identifiers are 32-bit quantities. In a long-lived
database it is possible for transaction IDs to wrap around. This
is not a fatal problem given appropriate maintenance procedures;
- see the <citetitle>Administrator's Guide</> for details. However, it is
+ see the &cite-admin; for details. However, it is
unwise to depend on uniqueness of transaction IDs over the long term
(more than one billion transactions).
</para>
limit of 2<superscript>32</> (4 billion) SQL commands within a single
transaction.
In practice this limit is not a problem --- note that the limit is on
- number of SQL queries, not number of tuples processed.
+ number of SQL commands, not number of tuples processed.
</para>
<para>
</indexterm>
<para>
- The <productname>PostgreSQL</productname> type system contains a number
- of special-purpose entries that are collectively called
- <firstterm>pseudo-types</>. A pseudo-type cannot be used as a column
- data type, but it can be used to declare a function's argument or result
- type. Each of the available pseudo-types is useful in situations where
- a function's behavior does not correspond to simply taking or returning
- a value of a specific SQL data type.
+ The <productname>PostgreSQL</productname> type system contains a
+ number of special-purpose entries that are collectively called
+ <firstterm>pseudo-types</>. A pseudo-type cannot be used as a
+ column data type, but it can be used to declare a function's
+ argument or result type. Each of the available pseudo-types is
+ useful in situations where a function's behavior does not
+ correspond to simply taking or returning a value of a specific SQL
+ data type. <xref linkend="datatype-pseudotypes-table"> lists the
+ existing pseudo-types.
</para>
- <para>
- <table tocentry="1">
+ <table id="datatype-pseudotypes-table">
<title>Pseudo-Types</title>
<tgroup cols="2">
<thead>
<row>
<entry><type>record</></entry>
- <entry>Identifies a function returning an unspecified tuple type</entry>
+ <entry>Identifies a function returning an unspecified row type</entry>
</row>
<row>
</tbody>
</tgroup>
</table>
- </para>
<para>
Functions coded in C (whether built-in or dynamically loaded) may be
<!--
-$Header: /cvsroot/pgsql/doc/src/sgml/datetime.sgml,v 2.28 2002/08/04 06:15:45 thomas Exp $
+$Header: /cvsroot/pgsql/doc/src/sgml/datetime.sgml,v 2.28.2.1 2002/11/10 12:45:41 petere Exp $
Date/time details
-->
<para>
<productname>PostgreSQL</productname> uses an internal heuristic
- parser for all date/time support. Dates and times are input as
+ parser for all date/time input support. Dates and times are input as
strings, and are broken up into distinct fields with a preliminary
determination of what kind of information may be in the
field. Each field is interpreted and either assigned a numeric
</para>
<sect1>
- <title>Date/Time Keywords</title>
+ <title>Date/Time Input Interpretation</title>
+
+ <para>
+ The date/time types are all decoded using a common set of routines.
+ </para>
+
+ <procedure>
+ <title>Date/Time Input Interpretation</title>
+
+ <step>
+ <para>
+ Break the input string into tokens and categorize each token as
+ a string, time, time zone, or number.
+ </para>
+
+ <substeps>
+ <step>
+ <para>
+ If the numeric token contains a colon (<literal>:</>), this is
+ a time string. Include all subsequent digits and colons.
+ </para>
+ </step>
+
+ <step>
+ <para>
+ If the numeric token contains a dash (<literal>-</>), slash
+ (<literal>/</>), or two or more dots (<literal>.</>), this is
+ a date string which may have a text month.
+ </para>
+ </step>
+
+ <step>
+ <para>
+ If the token is numeric only, then it is either a single field
+ or an ISO 8601 concatenated date (e.g.,
+ <literal>19990113</literal> for January 13, 1999) or time
+ (e.g. <literal>141516</literal> for 14:15:16).
+ </para>
+ </step>
+
+ <step>
+ <para>
+ If the token starts with a plus (<literal>+</>) or minus
+ (<literal>-</>), then it is either a time zone or a special
+ field.
+ </para>
+ </step>
+ </substeps>
+ </step>
+
+ <step>
+ <para>
+ If the token is a text string, match up with possible strings.
+ </para>
+
+ <substeps>
+ <step>
+ <para>
+ Do a binary-search table lookup for the token
+ as either a special string (e.g., <literal>today</literal>),
+ day (e.g., <literal>Thursday</literal>),
+ month (e.g., <literal>January</literal>),
+ or noise word (e.g., <literal>at</literal>, <literal>on</literal>).
+ </para>
+
+ <para>
+ Set field values and bit mask for fields.
+ For example, set year, month, day for <literal>today</literal>,
+ and additionally hour, minute, second for <literal>now</literal>.
+ </para>
+ </step>
+
+ <step>
+ <para>
+ If not found, do a similar binary-search table lookup to match
+ the token with a time zone.
+ </para>
+ </step>
+
+ <step>
+ <para>
+ If not found, throw an error.
+ </para>
+ </step>
+ </substeps>
+ </step>
+
+ <step>
+ <para>
+ The token is a number or number field.
+ </para>
+
+ <substeps>
+ <step>
+ <para>
+ If there are more than 4 digits,
+ and if no other date fields have been previously read, then interpret
+ as a <quote>concatenated date</quote> (e.g., <literal>19990118</literal>). 8
+ and 6 digits are interpreted as year, month, and day, while 7
+ and 5 digits are interpreted as year, day of year, respectively.
+ </para>
+ </step>
+
+ <step>
+ <para>
+ If the token is three digits
+ and a year has already been decoded, then interpret as day of year.
+ </para>
+ </step>
+
+ <step>
+ <para>
+ If four or six digits and a year has already been read, then
+ interpret as a time.
+ </para>
+ </step>
+
+ <step>
+ <para>
+ If four or more digits, then interpret as a year.
+ </para>
+ </step>
+
+ <step>
+ <para>
+ If in European date mode, and if the day field has not yet been read,
+ and if the value is less than or equal to 31, then interpret as a day.
+ </para>
+ </step>
+
+ <step>
+ <para>
+ If the month field has not yet been read,
+ and if the value is less than or equal to 12, then interpret as a month.
+ </para>
+ </step>
+
+ <step>
+ <para>
+ If the day field has not yet been read,
+ and if the value is less than or equal to 31, then interpret as a day.
+ </para>
+ </step>
+
+ <step>
+ <para>
+ If two digits or four or more digits, then interpret as a year.
+ </para>
+ </step>
+
+ <step>
+ <para>
+ Otherwise, throw an error.
+ </para>
+ </step>
+ </substeps>
+ </step>
+
+ <step>
+ <para>
+ If BC has been specified, negate the year and add one for
+ internal storage. (There is no year zero in the Gregorian
+ calendar, so numerically <literal>1BC</literal> becomes year
+ zero.)
+ </para>
+ </step>
+
+ <step>
+ <para>
+ If BC was not specified, and if the year field was two digits in length, then
+ adjust the year to 4 digits. If the field was less than 70, then add 2000;
+ otherwise, add 1900.
+
+ <tip>
+ <para>
+ Gregorian years AD 1-99 may be entered by using 4 digits with leading
+ zeros (e.g., <literal>0099</> is AD 99). Previous versions of
+ <productname>PostgreSQL</productname> accepted years with three
+ digits and with single digits, but as of version 7.0 the rules have
+ been tightened up to reduce the possibility of ambiguity.
+ </para>
+ </tip>
+ </para>
+ </step>
+ </procedure>
+ </sect1>
+
+
+ <sect1>
+ <title>Date/Time Key Words</title>
<para>
- <table tocentry="1">
+ <xref linkend="datetime-month-table"> shows the tokens that are
+ permissible as abbreviations for the names of the month.
+ </para>
+
+ <table id="datetime-month-table">
<title>Month Abbreviations</title>
<tgroup cols="2">
<thead>
<note>
<para>
- The month <literal>May</literal> has no explicit abbreviation, for obvious reasons.
+ The month May has no explicit abbreviation, for obvious reasons.
</para>
</note>
- </para>
<para>
- <table tocentry="1">
+ <xref linkend="datetime-dow-table"> shows the tokens that are
+ permissible as abbreviations for the names of the days of the
+ week.
+ </para>
+
+ <table id="datetime-dow-table">
<title>Day of the Week Abbreviations</title>
<tgroup cols="2">
<thead>
</tbody>
</tgroup>
</table>
- </para>
<para>
- <table tocentry="1">
- <title><productname>PostgreSQL</productname> Field Modifiers</title>
- <titleabbrev>Field Modifiers</titleabbrev>
+ <xref linkend="datetime-mod-table"> shows the tokens that serve
+ various modifier purposes.
+ </para>
+
+ <table id="datetime-mod-table">
+ <title>Date/Time Field Modifiers</title>
<tgroup cols="2">
<thead>
<row>
<tbody>
<row>
<entry><literal>ABSTIME</literal></entry>
- <entry>Keyword ignored</entry>
+ <entry>Key word ignored</entry>
</row>
<row>
<entry><literal>AM</literal></entry>
</row>
<row>
<entry><literal>AT</literal></entry>
- <entry>Keyword ignored</entry>
+ <entry>Key word ignored</entry>
</row>
<row>
<entry><literal>JULIAN</>, <literal>JD</>, <literal>J</></entry>
</row>
<row>
<entry><literal>ON</literal></entry>
- <entry>Keyword ignored</entry>
+ <entry>Key word ignored</entry>
</row>
<row>
<entry><literal>PM</literal></entry>
</tbody>
</tgroup>
</table>
- </para>
<para>
- The keyword <literal>ABSTIME</literal> is ignored for historical
+ The key word <literal>ABSTIME</literal> is ignored for historical
reasons; in very old releases of
- <productname>PostgreSQL</productname> invalid <type>ABSTIME</type>
- fields were emitted as <literal>Invalid Abstime</literal>. This is no
- longer the case however and this keyword will likely be dropped in
+ <productname>PostgreSQL</productname> invalid fields of type <type>abstime</type>
+ were emitted as <literal>Invalid Abstime</literal>. This is no
+ longer the case however and this key word will likely be dropped in
a future release.
</para>
- </sect1>
- <sect1 id="timezones">
- <title>Time Zones</title>
-
- <indexterm zone="timezones">
+ <indexterm>
<primary>time zones</primary>
</indexterm>
<para>
+ <xref linkend="datetime-timezone-table"> shows the time zone
+ abbreviations recognized by <productname>PostgreSQL</productname>.
<productname>PostgreSQL</productname> contains internal tabular
- information for time zone decoding, since there is no *nix standard
- system interface to provide access to general, cross-timezone
- information. The underlying OS <emphasis>is</emphasis> used to
- provide time zone information for <emphasis>output</emphasis>, however.
+ information for time zone decoding, since there is no standard
+ operating system interface to provide access to general,
+ cross-time zone information. The underlying operating system
+ <emphasis>is</emphasis> used to provide time zone information for
+ <emphasis>output</emphasis>, however.
</para>
<para>
- The following table of time zones recognized by
- <productname>PostgreSQL</productname> is organized by time
- zone offset from UTC, rather than alphabetically; this is intended
- to facilitate
+ The table is organized by time zone offset from <acronym>UTC</>,
+ rather than alphabetically; this is intended to facilitate
matching local usage with recognized abbreviations for cases where
these might differ.
+ </para>
- <table tocentry="1">
- <title><productname>PostgreSQL</productname> Recognized Time Zones</title>
- <titleabbrev>Time Zones</titleabbrev>
+ <table id="datetime-timezone-table">
+ <title>Time Zone Abbreviations</title>
<tgroup cols="3">
<thead>
<row>
</tbody>
</tgroup>
</table>
- </para>
- <sect2>
+ <formalpara>
<title>Australian Time Zones</title>
<para>
- Australian time zones and their naming variants
- account for fully one quarter of all time zones in the
- <productname>PostgreSQL</productname> time zone lookup table.
- There are two naming conflicts with time zones commonly used
- in the United States, <literal>CST</literal> and <literal>EST</literal>.
+ There are three naming conflicts between Australian time zone
+ names with time zones commonly used in North and South America:
+ <literal>ACST</literal>, <literal>CST</literal>, and
+ <literal>EST</literal>. If the run-time option
+ <varname>AUSTRALIAN_TIMEZONES</varname> is set to true then
+ <literal>ACST</literal>, <literal>CST</literal>,
+ <literal>EST</literal>, and <literal>SAT</literal> are interpreted
+ as Australian time zone names, as shown in <xref
+ linkend="datetime-oztz-table">. If it is false (which is the
+ default), then <literal>ACST</literal>, <literal>CST</literal>,
+ and <literal>EST</literal> are taken as American time zone names,
+ and <literal>SAT</literal> is interpreted as a noise word
+ indicating Saturday.
</para>
+ </formalpara>
- <para>
- If the run-time option <literal>AUSTRALIAN_TIMEZONES</literal> is set
- then <literal>CST</literal>, <literal>EST</literal>, and
- <literal>SAT</literal> will be
- interpreted as Australian timezone names. Without this option,
- <literal>CST</literal> and <literal>EST</literal> are taken as
- American timezone names, while <literal>SAT</literal> is interpreted as a
- noise word indicating <literal>Saturday</literal>.
-
- <table tocentry="1">
- <title><productname>PostgreSQL</productname> Australian Time Zones</title>
- <titleabbrev>Australian Time Zones</titleabbrev>
+ <table id="datetime-oztz-table">
+ <title>Australian Time Zone Abbreviations</title>
<tgroup cols="3">
<thead>
<row>
</tbody>
</tgroup>
</table>
- </para>
- </sect2>
-
- <sect2>
- <title>Date/Time Input Interpretation</title>
- <para>
- The date/time types are all decoded using a common set of routines.
- </para>
-
- <procedure>
- <title>Date/Time Input Interpretation</title>
-
- <step>
- <para>
- Break the input string into tokens and categorize each token as
- a string, time, time zone, or number.
- </para>
-
- <substeps>
- <step>
- <para>
- If the numeric token contains a colon (":"), this is a time
- string. Include all subsequent digits and colons.
- </para>
- </step>
-
- <step>
- <para>
- If the numeric token contains a dash ("-"), slash ("/"), or
- two or more dots ("."),
- this is a date string which may have a text month.
- </para>
- </step>
-
- <step>
- <para>
- If the token is numeric only, then it is either a single field
- or an ISO-8601 concatenated date
- (e.g. <literal>19990113</literal> for January 13, 1999)
- or time (e.g. 141516 for 14:15:16).
- </para>
- </step>
- <step>
- <para>
- If the token starts with a plus ("+") or minus ("-"),
- then it is either a time zone or a special field.
- </para>
- </step>
- </substeps>
- </step>
-
- <step>
- <para>
- If the token is a text string, match up with possible strings.
- </para>
-
- <substeps>
- <step>
- <para>
- Do a binary-search table lookup for the token
- as either a special string (e.g. <literal>today</literal>),
- day (e.g. <literal>Thursday</literal>),
- month (e.g. <literal>January</literal>),
- or noise word (e.g. <literal>at</literal>, <literal>on</literal>).
- </para>
- <para>
- Set field values and bit mask for fields.
- For example, set year, month, day for <literal>today</literal>,
- and additionally hour, minute, second for <literal>now</literal>.
- </para>
- </step>
-
- <step>
- <para>
- If not found, do a similar binary-search table lookup to match
- the token with a time zone.
- </para>
- </step>
-
- <step>
- <para>
- If not found, throw an error.
- </para>
- </step>
- </substeps>
- </step>
-
- <step>
- <para>
- The token is a number or number field.
- </para>
-
- <substeps>
- <step>
- <para>
- If there are more than 4 digits,
- and if no other date fields have been previously read, then interpret
- as a <quote>concatenated date</quote> (e.g. <literal>19990118</literal>). 8
- and 6 digits are interpreted as year, month, and day, while 7
- and 5 digits are interpreted as year, day of year, respectively.
- </para>
- </step>
-
- <step>
- <para>
- If the token is three digits
- and a year has already been decoded, then interpret as day of year.
- </para>
- </step>
-
- <step>
- <para>
- If four or six digits and a year has already been read, then
- interpret as a time.
- </para>
- </step>
-
- <step>
- <para>
- If four or more digits, then interpret as a year.
- </para>
- </step>
-
- <step>
- <para>
- If in European date mode, and if the day field has not yet been read,
- and if the value is less than or equal to 31, then interpret as a day.
- </para>
- </step>
-
- <step>
- <para>
- If the month field has not yet been read,
- and if the value is less than or equal to 12, then interpret as a month.
- </para>
- </step>
-
- <step>
- <para>
- If the day field has not yet been read,
- and if the value is less than or equal to 31, then interpret as a day.
- </para>
- </step>
-
- <step>
- <para>
- If two digits or four or more digits, then interpret as a year.
- </para>
- </step>
-
- <step>
- <para>
- Otherwise, throw an error.
- </para>
- </step>
- </substeps>
- </step>
-
- <step>
- <para>
- If BC has been specified, negate the year and add one for
- internal storage
- (there is no year zero in the Gregorian calendar, so numerically
- <literal>1BC</literal> becomes year zero).
- </para>
- </step>
-
- <step>
- <para>
- If BC was not specified, and if the year field was two digits in length, then
- adjust the year to 4 digits. If the field was less than 70, then add 2000;
- otherwise, add 1900.
-
- <tip>
- <para>
- Gregorian years 1-99AD may be entered by using 4 digits with leading
- zeros (e.g. 0099 is 99AD). Previous versions of
- <productname>PostgreSQL</productname> accepted years with three
- digits and with single digits, but as of version 7.0 the rules have
- been tightened up to reduce the possibility of ambiguity.
- </para>
- </tip>
- </para>
- </step>
- </procedure>
- </sect2>
- </sect1>
+ </sect1>
- <sect1 id="units-history">
+ <sect1 id="units-history">
<title>History of Units</title>
<note>
to noon UTC on 2 January 4713 BC.
</para>
- <para>
- <quote>Julian Day</quote> is different from <quote>Julian Date</quote>.
-
- The Julian calendar was introduced by Julius Caesar in 45 BC. It was
- in common use until the 1582, when countries started changing to the
- Gregorian calendar.
-
- In the Julian calendar, the tropical year is approximated as 365 1/4
- days = 365.25 days. This gives an error of about 1 day in
- 128 years.
- The accumulating calendar error prompted Pope Gregory XIII
- to reform the calendar in accordance with instructions
- from the Council of Trent.
+ <para>
+ The <quote>Julian Day</quote> is different from the <quote>Julian
+ Date</quote>. The Julian date refers to the Julian calendar, which
+ was introduced by Julius Caesar in 45 BC. It was in common use
+ until the 1582, when countries started changing to the Gregorian
+ calendar. In the Julian calendar, the tropical year is
+ approximated as 365 1/4 days = 365.25 days. This gives an error of
+ about 1 day in 128 years.
</para>
<para>
+ The accumulating calendar error prompted
+ Pope Gregory XIII to reform the calendar in accordance with
+ instructions from the Council of Trent.
In the Gregorian calendar, the tropical year is approximated as
365 + 97 / 400 days = 365.2425 days. Thus it takes approximately 3300
years for the tropical year to shift one day with respect to the
This was observed in Italy, Poland, Portugal, and Spain. Other Catholic
countries followed shortly after, but Protestant countries were
reluctant to change, and the Greek orthodox countries didn't change
- until the start of this century.
+ until the start of the 20th century.
The reform was observed by Great Britain and Dominions (including what is
now the USA) in 1752.
- Thus 2 Sep 1752 was followed by 14 Sep 1752.
+ Thus 2 September 1752 was followed by 14 September 1752.
- This is why Unix systems have <application>cal</application>
+ This is why Unix systems have the <command>cal</command> program
produce the following:
- <programlisting>
-% cal 9 1752
+<screen>
+$ <userinput>cal 9 1752</userinput>
September 1752
S M Tu W Th F S
1 2 14 15 16
17 18 19 20 21 22 23
24 25 26 27 28 29 30
- </programlisting>
+</screen>
</para>
- <note>
- <para>
- SQL92 states that
- <quote>Within the definition of a <quote>datetime literal</quote>,
- the <quote>datetime value</quote>s are constrained by the
- natural rules for dates and times
- according to the Gregorian calendar</quote>.
- Dates between 1752-09-03 and 1752-09-13, although eliminated in
- some countries by Papal fiat, conform to
- <quote>natural rules</quote> and are hence valid dates.
- </para>
- </note>
+ <note>
+ <para>
+ The SQL standard states that <quote>Within the definition of a
+ <quote>datetime literal</quote>, the <quote>datetime
+ value</quote>s are constrained by the natural rules for dates and
+ times according to the Gregorian calendar</quote>. Dates between
+ 1752-09-03 and 1752-09-13, although eliminated in some countries
+ by Papal fiat, conform to <quote>natural rules</quote> and are
+ hence valid dates.
+ </para>
+ </note>
<para>
Different calendars have been developed in various parts of the
calendar in 2637 BC.
The People's Republic of China uses the Gregorian calendar
- for civil purposes. Chinese calendar is used for determining
+ for civil purposes. The Chinese calendar is used for determining
festivals.
</para>
</sect1>
-<!-- $Header: /cvsroot/pgsql/doc/src/sgml/ddl.sgml,v 1.8 2002/10/24 21:10:58 tgl Exp $ -->
+<!-- $Header: /cvsroot/pgsql/doc/src/sgml/ddl.sgml,v 1.8.2.1 2002/11/10 12:45:42 petere Exp $ -->
<chapter id="ddl">
<title>Data Definition</title>
<para>
The identity (transaction ID) of the deleting transaction, or
zero for an undeleted tuple. It is possible for this field to
- be nonzero in a visible tuple: that usually indicates that the
+ be nonzero in a visible tuple: That usually indicates that the
deleting transaction hasn't committed yet, or that an attempted
deletion was rolled back.
</para>
price numeric <emphasis>CONSTRAINT positive_price</emphasis> CHECK (price > 0)
);
</programlisting>
- To specify a named constraint, use the key word
+ So, to specify a named constraint, use the key word
<literal>CONSTRAINT</literal> followed by an identifier followed
by the constraint definition.
</para>
</para>
<para>
- We say that the first two are column constraints, whereas the
+ We say that the first two constraints are column constraints, whereas the
third one is a table constraint because it is written separately
from the column definitions. Column constraints can also be
written as table constraints, while the reverse is not necessarily
<para>
In previous versions of <productname>PostgreSQL</productname>, the
default was not to get access to child tables. This was found to
- be error prone and is also in violation of SQL99. Under the old
+ be error prone and is also in violation of the SQL standard. Under the old
syntax, to get the sub-tables you append <literal>*</literal> to the table name.
For example
<programlisting>
standard. Therefore, many users consider qualified names to
really consist of
<literal><replaceable>username</>.<replaceable>tablename</></literal>.
- This is also supported by PostgreSQL if you create a per-user
+ This is how PostgreSQL will effectively behave if you create a per-user
schema for every user.
</para>
</screen>
and all the dependent objects will be removed. In this case, it
doesn't remove the orders table, it only removes the foreign key
- constraint. (If you want to check what DROP ... CASCADE will do,
- run DROP without CASCADE and read the NOTICEs.)
+ constraint. (If you want to check what <literal>DROP ... CASCADE</> will do,
+ run <command>DROP</> without <literal>CASCADE</> and read the <literal>NOTICE</> messages.)
</para>
<para>
-<!-- $Header: /cvsroot/pgsql/doc/src/sgml/dml.sgml,v 1.2 2002/10/20 05:05:46 tgl Exp $ -->
+<!-- $Header: /cvsroot/pgsql/doc/src/sgml/dml.sgml,v 1.2.2.1 2002/11/10 12:45:42 petere Exp $ -->
<chapter id="dml">
<title>Data Manipulation</title>
<para>
When a table is created, it contains no data. The first thing to
do before a database can be of much use is to insert data. Data is
- inserted one row at a time. This does not mean that there are no
- means to <quote>bulk load</quote> many rows efficiently. But there
- is no way to insert less than one row at a time. Even if you know
- only some column values, a complete row must be created.
+ conceptually inserted one row at a time. Of course you can also
+ insert more than one row, but there is no way to insert less than
+ one row at a time. Even if you know only some column values, a
+ complete row must be created.
</para>
<para>
INSERT INTO products DEFAULT VALUES;
</programlisting>
</para>
+
+ <tip>
+ <para>
+ To do <quote>bulk loads</quote>, that is, inserting a lot of data,
+ take a look at the <command>COPY</command> command (see
+ &cite-reference;). It is not as flexible as the
+ <command>INSERT</command> command, but more efficient.
+ </para>
+ </tip>
</sect1>
<sect1 id="dml-update">
<!--
-$Header: /cvsroot/pgsql/doc/src/sgml/func.sgml,v 1.129 2002/10/24 21:10:58 tgl Exp $
+$Header: /cvsroot/pgsql/doc/src/sgml/func.sgml,v 1.129.2.1 2002/11/10 12:45:42 petere Exp $
PostgreSQL documentation
-->
<productname>PostgreSQL</productname> provides a large number of
functions and operators for the built-in data types. Users can also
define their own functions and operators, as described in the
- <citetitle>Programmer's Guide</citetitle>. The
+ &cite-programmer;. 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.
and some explicitly marked functions, are not specified by the
<acronym>SQL</acronym>
standard. Some of this extended functionality is present in other
- <acronym>RDBMS</acronym> products, and in many cases this
+ <acronym>SQL</acronym> implementations, and in many cases this
functionality is compatible and consistent between various products.
</para>
<secondary>operators</secondary>
</indexterm>
- <table>
+ <para>
+ The usual comparison operators are available, shown in <xref
+ linkend="functions-comparison-table">.
+ </para>
+
+ <table id="functions-comparison-table">
<title>Comparison Operators</title>
<tgroup cols="2">
<thead>
</indexterm>
In addition to the comparison operators, the special
<token>BETWEEN</token> construct is available.
- <synopsis>
+<synopsis>
<replaceable>a</replaceable> BETWEEN <replaceable>x</replaceable> AND <replaceable>y</replaceable>
- </synopsis>
+</synopsis>
is equivalent to
- <synopsis>
+<synopsis>
<replaceable>a</replaceable> >= <replaceable>x</replaceable> AND <replaceable>a</replaceable> <= <replaceable>y</replaceable>
- </synopsis>
+</synopsis>
Similarly,
- <synopsis>
+<synopsis>
<replaceable>a</replaceable> NOT BETWEEN <replaceable>x</replaceable> AND <replaceable>y</replaceable>
- </synopsis>
+</synopsis>
is equivalent to
- <synopsis>
+<synopsis>
<replaceable>a</replaceable> < <replaceable>x</replaceable> OR <replaceable>a</replaceable> > <replaceable>y</replaceable>
- </synopsis>
+</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>
To check whether a value is or is not null, use the constructs
- <synopsis>
+<synopsis>
<replaceable>expression</replaceable> IS NULL
<replaceable>expression</replaceable> IS NOT NULL
- </synopsis>
- or the equivalent, but less standard, constructs
- <synopsis>
+</synopsis>
+ or the equivalent, but nonstandard, constructs
+<synopsis>
<replaceable>expression</replaceable> ISNULL
<replaceable>expression</replaceable> NOTNULL
- </synopsis>
+</synopsis>
</para>
<para>
<para>
Boolean values can also be tested using the constructs
- <synopsis>
+<synopsis>
<replaceable>expression</replaceable> IS TRUE
<replaceable>expression</replaceable> IS NOT TRUE
<replaceable>expression</replaceable> IS FALSE
<replaceable>expression</replaceable> IS NOT FALSE
<replaceable>expression</replaceable> IS UNKNOWN
<replaceable>expression</replaceable> IS NOT UNKNOWN
- </synopsis>
+</synopsis>
These are similar to <literal>IS NULL</literal> in that they will
always return true or false, never a null value, even when the operand is null.
A null input is treated as the logical value <quote>unknown</>.
Mathematical operators are provided for many
<productname>PostgreSQL</productname> types. For types without
common mathematical conventions for all possible permutations
- (e.g. date/time types) we
+ (e.g., date/time types) we
describe the actual behavior in subsequent sections.
</para>
- <table>
+ <para>
+ <xref linkend="functions-math-op-table"> shows the available mathematical operators.
+ </para>
+
+ <table id="functions-math-op-table">
<title>Mathematical Operators</title>
<tgroup cols="4">
<tbody>
<row>
<entry> <literal>+</literal> </entry>
- <entry>Addition</entry>
+ <entry>addition</entry>
<entry>2 + 3</entry>
<entry>5</entry>
</row>
<row>
<entry> <literal>-</literal> </entry>
- <entry>Subtraction</entry>
+ <entry>subtraction</entry>
<entry>2 - 3</entry>
<entry>-1</entry>
</row>
<row>
<entry> <literal>*</literal> </entry>
- <entry>Multiplication</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>division (integer division truncates results)</entry>
<entry>4 / 2</entry>
<entry>2</entry>
</row>
<row>
<entry> <literal>%</literal> </entry>
- <entry>Modulo (remainder)</entry>
+ <entry>modulo (remainder)</entry>
<entry>5 % 4</entry>
<entry>1</entry>
</row>
<row>
<entry> <literal>^</literal> </entry>
- <entry>Exponentiation</entry>
+ <entry>exponentiation</entry>
<entry>2.0 ^ 3.0</entry>
<entry>8</entry>
</row>
<row>
<entry> <literal>|/</literal> </entry>
- <entry>Square root</entry>
+ <entry>square root</entry>
<entry>|/ 25.0</entry>
<entry>5</entry>
</row>
<row>
<entry> <literal>||/</literal> </entry>
- <entry>Cube root</entry>
+ <entry>cube root</entry>
<entry>||/ 27.0</entry>
<entry>3</entry>
</row>
<row>
<entry> <literal>!</literal> </entry>
- <entry>Factorial</entry>
+ <entry>factorial</entry>
<entry>5 !</entry>
<entry>120</entry>
</row>
<row>
<entry> <literal>!!</literal> </entry>
- <entry>Factorial (prefix operator)</entry>
+ <entry>factorial (prefix operator)</entry>
<entry>!! 5</entry>
<entry>120</entry>
</row>
<row>
<entry> <literal>@</literal> </entry>
- <entry>Absolute value</entry>
+ <entry>absolute value</entry>
<entry>@ -5.0</entry>
<entry>5</entry>
</row>
<row>
<entry> <literal>&</literal> </entry>
- <entry>Binary AND</entry>
+ <entry>binary AND</entry>
<entry>91 & 15</entry>
<entry>11</entry>
</row>
<row>
<entry> <literal>|</literal> </entry>
- <entry>Binary OR</entry>
+ <entry>binary OR</entry>
<entry>32 | 3</entry>
<entry>35</entry>
</row>
<row>
<entry> <literal>#</literal> </entry>
- <entry>Binary XOR</entry>
+ <entry>binary XOR</entry>
<entry>17 # 5</entry>
<entry>20</entry>
</row>
<row>
<entry> <literal>~</literal> </entry>
- <entry>Binary NOT</entry>
+ <entry>binary NOT</entry>
<entry>~1</entry>
<entry>-2</entry>
</row>
<row>
<entry> << </entry>
- <entry>Binary shift left</entry>
+ <entry>binary shift left</entry>
<entry>1 << 4</entry>
<entry>16</entry>
</row>
<row>
<entry> >> </entry>
- <entry>Binary shift right</entry>
+ <entry>binary shift right</entry>
<entry>8 >> 2</entry>
<entry>2</entry>
</row>
<para>
The <quote>binary</quote> operators are also available for the bit
- string types <type>BIT</type> and <type>BIT VARYING</type>.
+ string types <type>BIT</type> and <type>BIT VARYING</type>, as
+ shown in <xref linkend="functions-math-bit-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 in the table.
+ </para>
- <table>
+ <table id="functions-math-bit-table">
<title>Bit String Binary Operators</title>
<tgroup cols="2">
</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>
+ <para>
+ <xref linkend="functions-math-func-table"> shows the available
+ mathematical functions. In the table, <literal>dp</literal>
+ indicates <type>double precision</type>. 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>. Functions returning a <type>numeric</type>
+ result take <type>numeric</type> input arguments, unless otherwise
+ specified. Many of these functions are implemented on top of the
+ host system's C library; accuracy and behavior in boundary cases
+ could therefore vary depending on the host system.
+ </para>
- <table tocentry="1">
+ <table id="functions-math-func-table">
<title>Mathematical Functions</title>
<tgroup cols="5">
<thead>
<tbody>
<row>
<entry><function>abs</function>(<replaceable>x</replaceable>)</entry>
- <entry>(same as x)</entry>
+ <entry>(same as <replaceable>x</>)</entry>
<entry>absolute value</entry>
<entry><literal>abs(-17.4)</literal></entry>
<entry>17.4</entry>
</tgroup>
</table>
- <para>
- In the table above, <literal>dp</literal> indicates <type>double precision</type>.
- 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>.
- Functions returning a <type>numeric</type> result take
- <type>numeric</type> input arguments, unless otherwise specified.
- Many of these functions are implemented on top
- of the host system's C library; accuracy and behavior in boundary cases
- could therefore vary depending on the host system.
- </para>
+ <para>
+ Finally, <xref linkend="functions-math-trig-table"> shows the
+ available trigonometric functions. All trigonometric functions
+ have arguments and return values of type <type>double
+ precision</type>.
+ </para>
- <table>
+ <table id="functions-math-trig-table">
<title>Trigonometric Functions</title>
<tgroup cols="2">
</tgroup>
</table>
- <para>
- All trigonometric functions have arguments and return values of
- type <type>double precision</type>.
- </para>
-
</sect1>
<para>
<acronym>SQL</acronym> defines some string functions with a special syntax where
- certain keywords rather than commas are used to separate the
+ certain key words 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">.)
<parameter>string</parameter> </entry>
<entry> <type>text</type> </entry>
<entry>
- string concatenation
+ String concatenation
<indexterm>
<primary>character strings</primary>
<secondary>concatenation</secondary>
</indexterm>
</entry>
- <entry><literal>'Postgre' || 'SQL'</literal></entry>
+ <entry><literal>'Post' || 'greSQL'</literal></entry>
<entry><literal>PostgreSQL</literal></entry>
</row>
<row>
<entry><function>bit_length</function>(<parameter>string</parameter>)</entry>
<entry><type>integer</type></entry>
- <entry>number of bits in string</entry>
+ <entry>Number of bits in string</entry>
<entry><literal>bit_length('jose')</literal></entry>
<entry><literal>32</literal></entry>
</row>
<entry><function>char_length</function>(<parameter>string</parameter>) or <function>character_length</function>(<parameter>string</parameter>)</entry>
<entry><type>integer</type></entry>
<entry>
- number of characters in string
+ Number of characters in string
<indexterm>
<primary>character strings</primary>
<secondary>length</secondary>
names.
</entry>
<entry><literal>convert('PostgreSQL' using iso_8859_1_to_utf_8)</literal></entry>
- <entry><literal>'PostgreSQL'</literal> in UNICODE (UTF-8) encoding</entry>
+ <entry><literal>'PostgreSQL'</literal> in Unicode (UTF-8) encoding</entry>
</row>
<row>
<entry><function>lower</function>(<parameter>string</parameter>)</entry>
<entry><type>text</type></entry>
- <entry>Convert string to lower case.</entry>
+ <entry>Convert string to lower case</entry>
<entry><literal>lower('TOM')</literal></entry>
<entry><literal>tom</literal></entry>
</row>
<row>
<entry><function>octet_length</function>(<parameter>string</parameter>)</entry>
<entry><type>integer</type></entry>
- <entry>number of bytes in string</entry>
+ <entry>Number of bytes in string</entry>
<entry><literal>octet_length('jose')</literal></entry>
<entry><literal>4</literal></entry>
</row>
<entry><function>overlay</function>(<parameter>string</parameter> placing <parameter>string</parameter> from <type>integer</type> <optional>for <type>integer</type></optional>)</entry>
<entry><type>text</type></entry>
<entry>
- insert substring
+ Insert substring
<indexterm>
<primary>overlay</primary>
</indexterm>
<row>
<entry><function>position</function>(<parameter>substring</parameter> in <parameter>string</parameter>)</entry>
<entry><type>integer</type></entry>
- <entry>location of specified substring</entry>
+ <entry>Location of specified substring</entry>
<entry><literal>position('om' in 'Thomas')</literal></entry>
<entry><literal>3</literal></entry>
</row>
<entry><function>substring</function>(<parameter>string</parameter> <optional>from <type>integer</type></optional> <optional>for <type>integer</type></optional>)</entry>
<entry><type>text</type></entry>
<entry>
- extract substring
+ Extract substring
<indexterm>
<primary>substring</primary>
</indexterm>
<entry><function>substring</function>(<parameter>string</parameter> from <replaceable>pattern</replaceable>)</entry>
<entry><type>text</type></entry>
<entry>
- extract substring matching POSIX regular expression
+ Extract substring matching POSIX regular expression
<indexterm>
<primary>substring</primary>
</indexterm>
<entry><function>substring</function>(<parameter>string</parameter> from <replaceable>pattern</replaceable> for <replaceable>escape</replaceable>)</entry>
<entry><type>text</type></entry>
<entry>
- extract substring matching SQL99 regular expression
+ Extract substring matching SQL regular expression
<indexterm>
<primary>substring</primary>
</indexterm>
</entry>
<entry><type>text</type></entry>
<entry>
- Removes the longest string containing only the
+ Remove the longest string containing only the
<parameter>characters</parameter> (a space by default) from the
- beginning/end/both ends of the <parameter>string</parameter>.
+ beginning/end/both ends of the <parameter>string</parameter>
</entry>
<entry><literal>trim(both 'x' from 'xTomxx')</literal></entry>
<entry><literal>Tom</literal></entry>
<row>
<entry><function>upper</function>(<parameter>string</parameter>)</entry>
<entry><type>text</type></entry>
- <entry>Convert string to upper case.</entry>
+ <entry>Convert string to upper case</entry>
<entry><literal>upper('tom')</literal></entry>
<entry><literal>TOM</literal></entry>
</row>
<para>
Additional string manipulation functions are available and are
- listed below. Some of them are used internally to implement the
- <acronym>SQL</acronym>-standard string functions listed above.
+ listed in <xref linkend="functions-string-other">. Some of them are used internally to implement the
+ <acronym>SQL</acronym>-standard string functions listed in <xref linkend="functions-string-sql">.
</para>
<table id="functions-string-other">
<row>
<entry><function>ascii</function>(<type>text</type>)</entry>
<entry>integer</entry>
- <entry>Returns the <acronym>ASCII</acronym> code of the first character of the argument.</entry>
+ <entry><acronym>ASCII</acronym> code of the first character of the argument.</entry>
<entry><literal>ascii('x')</literal></entry>
<entry><literal>120</literal></entry>
</row>
<entry>
Remove (trim) the longest string consisting only of characters
in <parameter>trim</parameter> from the start and end of
- <parameter>string</parameter>.
+ <parameter>string</parameter>
</entry>
<entry><literal>btrim('xyxtrimyyx','xy')</literal></entry>
<entry><literal>trim</literal></entry>
<row>
<entry><function>chr</function>(<type>integer</type>)</entry>
<entry><type>text</type></entry>
- <entry>Returns the character with the given <acronym>ASCII</acronym> code.</entry>
+ <entry>Character with the given <acronym>ASCII</acronym> code</entry>
<entry><literal>chr(65)</literal></entry>
<entry><literal>A</literal></entry>
</row>
</entry>
<entry><type>text</type></entry>
<entry>
- Converts string using <parameter>dest_encoding</parameter>.
+ Convert string to <parameter>dest_encoding</parameter>.
The original encoding is specified by
<parameter>src_encoding</parameter>. If
<parameter>src_encoding</parameter> is omitted, database
</entry>
<entry><type>bytea</type></entry>
<entry>
- Decodes binary data from <parameter>string</parameter> previously
- encoded with encode(). Parameter type is same as in encode().
+ Decode binary data from <parameter>string</parameter> previously
+ encoded with <function>encode()</>. Parameter type is same as in <function>encode()</>.
</entry>
<entry><literal>decode('MTIzAAE=', 'base64')</literal></entry>
<entry><literal>123\000\001</literal></entry>
</entry>
<entry><type>text</type></entry>
<entry>
- Encodes binary data to <acronym>ASCII</acronym>-only representation. Supported
- types are: 'base64', 'hex', 'escape'.
+ Encode binary data to <acronym>ASCII</acronym>-only representation. Supported
+ types are: base64, hex, escape.
</entry>
<entry><literal>encode('123\\000\\001', 'base64')</literal></entry>
<entry><literal>MTIzAAE=</literal></entry>
<row>
<entry><function>initcap</function>(<type>text</type>)</entry>
<entry><type>text</type></entry>
- <entry>Converts first letter of each word (whitespace separated) to upper case.</entry>
+ <entry>Convert first letter of each word (whitespace separated) to upper case</entry>
<entry><literal>initcap('hi thomas')</literal></entry>
<entry><literal>Hi Thomas</literal></entry>
</row>
<entry><function>length</function>(<parameter>string</parameter>)</entry>
<entry><type>integer</type></entry>
<entry>
- length of string
+ Length of string
<indexterm>
<primary>character strings</primary>
<secondary>length</secondary>
</entry>
<entry>text</entry>
<entry>
- Fills up the <parameter>string</parameter> to length
+ Fill up the <parameter>string</parameter> to length
<parameter>length</parameter> by prepending the characters
<parameter>fill</parameter> (a space by default). If the
<parameter>string</parameter> is already longer than
<entry><function>ltrim</function>(<parameter>string</parameter> <type>text</type>, <parameter>text</parameter> <type>text</type>)</entry>
<entry><type>text</type></entry>
<entry>
- Removes the longest string containing only characters from
+ Remove the longest string containing only characters from
<parameter>trim</parameter> from the start of the string.
</entry>
<entry><literal>ltrim('zzzytrim','xyz')</literal></entry>
<entry><function>pg_client_encoding</function>()</entry>
<entry><type>name</type></entry>
<entry>
- Returns current client encoding name.
+ Current client encoding name.
</entry>
<entry><literal>pg_client_encoding()</literal></entry>
<entry><literal>SQL_ASCII</literal></entry>
<entry><function>quote_ident</function>(<parameter>string</parameter> text)</entry>
<entry><type>text</type></entry>
<entry>
- Returns the given string suitably quoted to be used as an identifier
+ Return the given string suitably quoted to be used as an identifier
in an SQL query string.
Quotes are added only if necessary (i.e., if the string contains
non-identifier characters or would be case-folded).
<entry><function>quote_literal</function>(<parameter>string</parameter> text)</entry>
<entry><type>text</type></entry>
<entry>
- Returns the given string suitably quoted to be used as a literal
+ Return the given string suitably quoted to be used as a literal
in an SQL query string.
Embedded quotes and backslashes are properly doubled.
</entry>
<row>
<entry><function>repeat</function>(<type>text</type>, <type>integer</type>)</entry>
<entry><type>text</type></entry>
- <entry>Repeat text a number of times.</entry>
+ <entry>Repeat text a number of times</entry>
<entry><literal>repeat('Pg', 4)</literal></entry>
<entry><literal>PgPgPgPg</literal></entry>
</row>
</entry>
<entry><type>text</type></entry>
<entry>
- Fills up the <parameter>string</parameter> to length
+ Fill up the <parameter>string</parameter> to length
<parameter>length</parameter> by appending the characters
<parameter>fill</parameter> (a space by default). If the
<parameter>string</parameter> is already longer than
text, <parameter>trim</parameter> text)</entry>
<entry><type>text</type></entry>
<entry>
- Removes the longest string containing only characters from
+ Remove the longest string containing only characters from
<parameter>trim</parameter> from the end of the string.
</entry>
<entry><literal>rtrim('trimxxxx','x')</literal></entry>
<entry><function>strpos</function>(<parameter>string</parameter>, <parameter>substring</parameter>)</entry>
<entry><type>text</type></entry>
<entry>
- Locates specified substring. (same as
+ Locate specified substring (same as
<literal>position(<parameter>substring</parameter> in
<parameter>string</parameter>)</literal>, but note the reversed
argument order)
<entry><function>substr</function>(<parameter>string</parameter>, <parameter>from</parameter> <optional>, <parameter>count</parameter></optional>)</entry>
<entry><type>text</type></entry>
<entry>
- Extracts specified substring. (same as
+ Extract specified substring (same as
<literal>substring(<parameter>string</parameter> from <parameter>from</parameter> for <parameter>count</parameter>)</literal>)
</entry>
<entry><literal>substr('alphabet', 3, 2)</literal></entry>
<entry><function>to_ascii</function>(<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>
+ Convert text to <acronym>ASCII</acronym> from other encoding
+ <footnote>
+ <para>
+ The <function>to_ascii</function> function supports conversion from
+ <literal>LATIN1</>, <literal>LATIN2</>, and <literal>WIN1250</> only.
+ </para>
+ </footnote>
+ </entry>
+
<entry><literal>to_ascii('Karel')</literal></entry>
<entry><literal>Karel</literal></entry>
</row>
or <type>bigint</type>)</entry>
<entry><type>text</type></entry>
<entry>Convert <parameter>number</parameter> to its equivalent hexadecimal
- representation.
+ representation
</entry>
<entry><literal>to_hex(9223372036854775807::bigint)</literal></entry>
<entry><literal>7fffffffffffffff</literal></entry>
</tgroup>
</table>
- <para>
- The <function>to_ascii</function> function supports conversion from
- <literal>LATIN1</>, <literal>LATIN2</>, and <literal>WIN1250</> only.
- </para>
-
<table id="conversion-names">
<title>Built-in Conversions</title>
<para>
<acronym>SQL</acronym> defines some string functions with a
special syntax where
- certain keywords rather than commas are used to separate the
+ certain key words rather than commas are used to separate the
arguments. Details are in
<xref linkend="functions-binarystring-sql">.
Some functions are also implemented using the regular syntax for
<parameter>string</parameter> </entry>
<entry> <type>bytea</type> </entry>
<entry>
- string concatenation
+ String concatenation
<indexterm>
<primary>binary strings</primary>
<secondary>concatenation</secondary>
</indexterm>
</entry>
- <entry><literal>'\\\\Postgre'::bytea || '\\047SQL\\000'::bytea</literal></entry>
- <entry><literal>\\Postgre'SQL\000</literal></entry>
+ <entry><literal>'\\\\Post'::bytea || '\\047greSQL\\000'::bytea</literal></entry>
+ <entry><literal>\\Post'greSQL\000</literal></entry>
</row>
<row>
<entry><function>octet_length</function>(<parameter>string</parameter>)</entry>
<entry><type>integer</type></entry>
- <entry>number of bytes in binary string</entry>
+ <entry>Number of bytes in binary string</entry>
<entry><literal>octet_length('jo\\000se'::bytea)</literal></entry>
<entry><literal>5</literal></entry>
</row>
<row>
<entry><function>position</function>(<parameter>substring</parameter> in <parameter>string</parameter>)</entry>
<entry><type>integer</type></entry>
- <entry>location of specified substring</entry>
+ <entry>Location of specified substring</entry>
<entry><literal>position('\\000om'::bytea in 'Th\\000omas'::bytea)</literal></entry>
<entry><literal>3</literal></entry>
</row>
<entry><function>substring</function>(<parameter>string</parameter> <optional>from <type>integer</type></optional> <optional>for <type>integer</type></optional>)</entry>
<entry><type>bytea</type></entry>
<entry>
- extract substring
+ Extract substring
<indexterm>
<primary>substring</primary>
</indexterm>
</entry>
<entry><type>bytea</type></entry>
<entry>
- Removes the longest string containing only the
+ Remove the longest string containing only the
<parameter>characters</parameter> from the
- beginning/end/both ends of the <parameter>string</parameter>.
+ beginning/end/both ends of the <parameter>string</parameter>
</entry>
<entry><literal>trim('\\000'::bytea from '\\000Tom\\000'::bytea)</literal></entry>
<entry><literal>Tom</literal></entry>
</table>
<para>
- Additional binary string manipulation functions are available and are
- listed below. Some of them are used internally to implement the
- <acronym>SQL</acronym>-standard string functions listed above.
+ Additional binary string manipulation functions are available and
+ are listed in <xref linkend="functions-binarystring-other">. Some
+ of them are used internally to implement the
+ <acronym>SQL</acronym>-standard string functions listed in <xref
+ linkend="functions-binarystring-sql">.
</para>
<table id="functions-binarystring-other">
<entry><function>length</function>(<parameter>string</parameter>)</entry>
<entry><type>integer</type></entry>
<entry>
- length of binary string
+ Length of binary string
<indexterm>
<primary>binary strings</primary>
<secondary>length</secondary>
</entry>
<entry><type>text</type></entry>
<entry>
- Encodes binary string to <acronym>ASCII</acronym>-only representation. Supported
- types are: 'base64', 'hex', 'escape'.
+ Encode binary string to <acronym>ASCII</acronym>-only representation. Supported
+ types are: base64, hex, escape.
</entry>
<entry><literal>encode('123\\000456'::bytea, 'escape')</literal></entry>
<entry><literal>123\000456</literal></entry>
</entry>
<entry><type>bytea</type></entry>
<entry>
- Decodes binary string from <parameter>string</parameter> previously
- encoded with encode(). Parameter type is same as in encode().
+ Decode binary string from <parameter>string</parameter> previously
+ encoded with <literal>encode()</>. Parameter type is same as in <literal>encode()</>.
</entry>
<entry><literal>decode('123\\000456', 'escape')</literal></entry>
<entry><literal>123\000456</literal></entry>
<primary>like</primary>
</indexterm>
- <synopsis>
+<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>
+</synopsis>
<para>
Every <replaceable>pattern</replaceable> defines a set of strings.
of zero or more characters.
</para>
- <informalexample>
- <para>
- Some examples:
- <programlisting>
+ <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>
-
+</programlisting>
+ </para>
+
<para>
<function>LIKE</function> pattern matches always cover the entire
string. To match a pattern anywhere within a string, the
<primary>substring</primary>
</indexterm>
- <synopsis>
+<synopsis>
<replaceable>string</replaceable> SIMILAR TO <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
<replaceable>string</replaceable> NOT SIMILAR TO <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
- </synopsis>
+</synopsis>
<para>
The <function>SIMILAR TO</function> operator returns true or false
be specified with <literal>ESCAPE</>.
</para>
- <informalexample>
- <para>
- Some examples:
- <programlisting>
+ <para>
+ Some examples:
+<programlisting>
'abc' SIMILAR TO 'abc' <lineannotation>true</lineannotation>
'abc' SIMILAR TO 'a' <lineannotation>false</lineannotation>
'abc' SIMILAR TO '%(b|d)%' <lineannotation>true</lineannotation>
'abc' SIMILAR TO '(b|c)%' <lineannotation>false</lineannotation>
- </programlisting>
- </para>
- </informalexample>
+</programlisting>
+ </para>
<para>
- The SUBSTRING function with three parameters,
- <function>SUBSTRING</function>(<parameter>string</parameter> FROM
+ The <function>SUBSTRING</> function with three parameters,
+ <function>SUBSTRING(<parameter>string</parameter> FROM
<replaceable>pattern</replaceable> FOR
- <replaceable>escape</replaceable>), provides extraction of a substring
- that matches a SQL99 regular expression pattern. As with SIMILAR TO,
- the specified pattern must match to the entire data string, else the
- function fails and returns NULL. To indicate the part of the pattern
- that should be returned on success, SQL99 specifies that the pattern
- must contain two occurrences of the escape character followed by
- double quote (<literal>"</>). The text matching the portion of the
- pattern between these markers is returned.
+ <replaceable>escape</replaceable>)</function>, provides
+ extraction of a substring that matches a SQL99 regular expression
+ pattern. As with <literal>SIMILAR TO</>, the specified pattern
+ must match to the entire data string, else the function fails and
+ returns null. To indicate the part of the pattern that should be
+ returned on success, SQL99 specifies that the pattern must
+ contain two occurrences of the escape character followed by
+ double quote (<literal>"</>). The text matching the portion of
+ the pattern between these markers is returned.
</para>
- <informalexample>
- <para>
- Some examples:
- <programlisting>
+ <para>
+ Some examples:
+<programlisting>
SUBSTRING('foobar' FROM '%#"o_b#"%' FOR '#') <lineannotation>oob</lineannotation>
SUBSTRING('foobar' FROM '#"o_b#"%' FOR '#') <lineannotation>NULL</lineannotation>
- </programlisting>
- </para>
- </informalexample>
-
+</programlisting>
+ </para>
</sect2>
<sect2 id="functions-posix-regexp">
<seealso>pattern matching</seealso>
</indexterm>
- <table>
+ <para>
+ <xref linkend="functions-posix-table"> lists the available
+ operators for pattern matching using POSIX regular expressions.
+ </para>
+
+ <table id="functions-posix-table">
<title>Regular Expression Match Operators</title>
<tgroup cols="3">
end of the string.
</para>
- <informalexample>
- <para>
- Some examples:
- <programlisting>
+ <para>
+ Some examples:
+<programlisting>
'abc' ~ 'abc' <lineannotation>true</lineannotation>
'abc' ~ '^a' <lineannotation>true</lineannotation>
'abc' ~ '(b|d)' <lineannotation>true</lineannotation>
'abc' ~ '^(b|c)' <lineannotation>false</lineannotation>
- </programlisting>
- </para>
- </informalexample>
+</programlisting>
+ </para>
<para>
- The SUBSTRING function with two parameters,
- <function>SUBSTRING</function>(<parameter>string</parameter> FROM
- <replaceable>pattern</replaceable>), provides extraction of a substring
- that matches a POSIX regular expression pattern. It returns NULL if
+ The <function>SUBSTRING</> function with two parameters,
+ <function>SUBSTRING(<parameter>string</parameter> FROM
+ <replaceable>pattern</replaceable>)</function>, provides extraction of a substring
+ that matches a POSIX regular expression pattern. It returns null if
there is no match, otherwise the portion of the text that matched the
pattern. But if the pattern contains any parentheses, the portion
of the text that matched the first parenthesized subexpression (the
exception.
</para>
- <informalexample>
- <para>
- Some examples:
- <programlisting>
+ <para>
+ Some examples:
+<programlisting>
SUBSTRING('foobar' FROM 'o.b') <lineannotation>oob</lineannotation>
SUBSTRING('foobar' FROM 'o(.)b') <lineannotation>o</lineannotation>
- </programlisting>
- </para>
- </informalexample>
+</programlisting>
+ </para>
<!-- derived from the re_format.7 man page -->
<para>
<primary>formatting</primary>
</indexterm>
- <note>
- <title>Author</title>
- <para>
- Written by Karel Zak (<email>zakkr@zf.jcu.cz</email>) on 2000-01-24
- </para>
- </note>
-
<para>
The <productname>PostgreSQL</productname> formatting functions
provide a powerful set of tools for converting various data types
(date/time, integer, floating point, numeric) to formatted strings
and for converting from formatted strings to specific data types.
+ <xref linkend="functions-formatting-table"> lists them.
These functions all follow a common calling convention: the first
argument is the value to be formatted and the second argument is a
template that defines the output or input format.
</para>
- <table tocentry="1">
+ <table id="functions-formatting-table">
<title>Formatting Functions</title>
<tgroup cols="4">
<thead>
<row>
<entry><function>to_char</function>(<type>int</type>, <type>text</type>)</entry>
<entry><type>text</type></entry>
- <entry>convert int4/int8 to string</entry>
+ <entry>convert integer to string</entry>
<entry><literal>to_char(125, '999')</literal></entry>
</row>
<row>
values to be found there.
</para>
- <table tocentry="1">
+ <para>
+ <xref linkend="functions-formatting-datetime-table"> shows the
+ template patterns available for formatting date and time values.
+ </para>
+
+ <table id="functions-formatting-datetime-table">
<title>Template patterns for date/time conversions</title>
<tgroup cols="2">
<thead>
</row>
<row>
<entry><literal>TZ</literal></entry>
- <entry>timezone name - upper case</entry>
+ <entry>time-zone name - upper case</entry>
</row>
<row>
<entry><literal>tz</literal></entry>
- <entry>timezone name - lower case</entry>
+ <entry>time-zone name - lower case</entry>
</row>
</tbody>
</tgroup>
behavior. For example, <quote><literal>FMMonth</literal></quote>
is the <quote><literal>Month</literal></quote> pattern with the
<quote><literal>FM</literal></quote> prefix.
+ <xref linkend="functions-formatting-datetimemod-table"> shows the
+ modifier patterns for date/time formatting.
</para>
- <table tocentry="1">
+ <table id="functions-formatting-datetimemod-table">
<title>Template pattern modifiers for date/time conversions</title>
<tgroup cols="3">
<thead>
</row>
<row>
<entry><literal>FX</literal> prefix</entry>
- <entry>Fixed format global option (see below)</entry>
+ <entry>fixed format global option (see usage notes)</entry>
<entry><literal>FX Month DD Day</literal></entry>
</row>
<row>
</table>
<para>
- Usage notes:
+ Usage notes for the date/time formatting:
<itemizedlist>
<listitem>
<para>
- <literal>FM</literal> suppresses leading zeroes or trailing blanks
+ <literal>FM</literal> suppresses leading zeroes and trailing blanks
that would otherwise be added to make the output of a pattern be
fixed-width.
</para>
templates and will be output literally. You can put a substring
in double quotes to force it to be interpreted as literal text
even if it contains pattern keywords. For example, in
- <literal>'"Hello Year: "YYYY'</literal>, the <literal>YYYY</literal>
- will be replaced by year data, but the single <literal>Y</literal>
+ <literal>'"Hello Year "YYYY'</literal>, the <literal>YYYY</literal>
+ will be replaced by the year data, but the single <literal>Y</literal> in <quote>Year</quote>
will not be.
</para>
</listitem>
</itemizedlist>
</para>
- <table tocentry="1">
+ <para>
+ <xref linkend="functions-formatting-numeric-table"> shows the
+ template patterns available for formatting numeric values.
+ </para>
+
+ <table id="functions-formatting-numeric-table">
<title>Template patterns for numeric conversions</title>
<tgroup cols="2">
<thead>
</table>
<para>
- Usage notes:
+ Usage notes for the numeric formatting:
<itemizedlist>
<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.
+ not available it outputs a space.
</para>
</listitem>
</itemizedlist>
</para>
- <table tocentry="1">
+ <para>
+ <xref linkend="functions-formatting-examples-table"> shows some
+ examples of the use of the <function>to_char</function> function.
+ </para>
+
+ <table id="functions-formatting-examples-table">
<title><function>to_char</function> Examples</title>
<tgroup cols="2">
<thead>
<sect1 id="functions-datetime">
<title>Date/Time Functions and Operators</title>
- <para>
- <xref linkend="functions-datetime-table"> shows the available
- functions for date/time value processing.
- <xref linkend="operators-datetime-table"> illustrates the
- behaviors of the basic arithmetic
- operators (<literal>+</literal>, <literal>*</literal>, etc.).
- For formatting functions, refer to <xref
- linkend="functions-formatting">. You should be familiar with the
- background information on date/time data types (see <xref
- linkend="datatype-datetime">).
- </para>
-
- <para>
- The date/time operators described below behave similarly for types
- involving time zones as well as those without.
+ <para>
+ <xref linkend="functions-datetime-table"> shows the available
+ functions for date/time value processing, with details appearing in
+ the following subsections. <xref
+ linkend="operators-datetime-table"> illustrates the behaviors of
+ the basic arithmetic operators (<literal>+</literal>,
+ <literal>*</literal>, etc.). For formatting functions, refer to
+ <xref linkend="functions-formatting">. You should be familiar with
+ the background information on date/time data types (see <xref
+ linkend="datatype-datetime">). The date/time operators described
+ below behave similarly for types involving time zones as well as
+ those without.
+ </para>
<table id="operators-datetime-table">
<title>Date/Time Operators</title>
<tbody>
<row>
<entry> <literal>+</literal> </entry>
- <entry><type>timestamp</type> '2001-09-28 01:00' + <type>interval</type> '23 hours'</entry>
- <entry><type>timestamp</type> '2001-09-29 00:00'</entry>
+ <entry><literal>timestamp '2001-09-28 01:00' + interval '23 hours'</literal></entry>
+ <entry><literal>timestamp '2001-09-29 00:00'</literal></entry>
</row>
<row>
<entry> <literal>+</literal> </entry>
- <entry><type>date</type> '2001-09-28' + <type>interval</type> '1 hour'</entry>
- <entry><type>timestamp</type> '2001-09-28 01:00'</entry>
+ <entry><literal>date '2001-09-28' + interval '1 hour'</literal></entry>
+ <entry><literal>timestamp '2001-09-28 01:00'</literal></entry>
</row>
<row>
<entry> <literal>+</literal> </entry>
- <entry><type>time</type> '01:00' + <type>interval</type> '3 hours'</entry>
- <entry><type>time</type> '04:00'</entry>
+ <entry><literal>time '01:00' + interval '3 hours'</literal></entry>
+ <entry><literal>time '04:00'</literal></entry>
</row>
<row>
<entry> <literal>-</literal> </entry>
- <entry><type>timestamp</type> '2001-09-28 23:00' - <type>interval</type> '23 hours'</entry>
- <entry><type>timestamp</type> '2001-09-28'</entry>
+ <entry><literal>timestamp '2001-09-28 23:00' - interval '23 hours'</literal></entry>
+ <entry><literal>timestamp '2001-09-28'</literal></entry>
</row>
<row>
<entry> <literal>-</literal> </entry>
- <entry><type>date</type> '2001-09-28' - <type>interval</type> '1 hour'</entry>
- <entry><type>timestamp</type> '2001-09-27 23:00'</entry>
+ <entry><literal>date '2001-09-28' - interval '1 hour'</literal></entry>
+ <entry><literal>timestamp '2001-09-27 23:00'</literal></entry>
</row>
<row>
<entry> <literal>-</literal> </entry>
- <entry><type>time</type> '05:00' - <type>interval</type> '2 hours'</entry>
- <entry><type>time</type> '03:00'</entry>
+ <entry><literal>time '05:00' - interval '2 hours'</literal></entry>
+ <entry><literal>time '03:00'</literal></entry>
</row>
<row>
<entry> <literal>-</literal> </entry>
- <entry><type>interval</type> '2 hours' - <type>time</type> '05:00'</entry>
- <entry><type>time</type> '03:00:00'</entry>
+ <entry><literal>interval '2 hours' - time '05:00'</literal></entry>
+ <entry><literal>time '03:00:00'</literal></entry>
</row>
<row>
<entry> <literal>*</literal> </entry>
- <entry><type>interval</type> '1 hour' * <type>int</type> '3'</entry>
- <entry><type>interval</type> '03:00'</entry>
+ <entry><literal>interval '1 hour' * int '3'</literal></entry>
+ <entry><literal>interval '03:00'</literal></entry>
</row>
<row>
<entry> <literal>/</literal> </entry>
- <entry><type>interval</type> '1 hour' / <type>int</type> '3'</entry>
- <entry><type>interval</type> '00:20'</entry>
+ <entry><literal>interval '1 hour' / int '3'</literal></entry>
+ <entry><literal>interval '00:20'</literal></entry>
</row>
</tbody>
</tgroup>
</table>
- </para>
-
- <para>
- The date/time functions are summarized below, with additional
- details in subsequent sections.
<table id="functions-datetime-table">
<title>Date/Time Functions</title>
<row>
<entry><function>current_date</function></entry>
<entry><type>date</type></entry>
- <entry>Today's date; see <link linkend="functions-datetime-current">below</link>
+ <entry>Today's date; see <xref linkend="functions-datetime-current">
</entry>
<entry></entry>
<entry></entry>
<row>
<entry><function>current_time</function></entry>
<entry><type>time with time zone</type></entry>
- <entry>Time of day; see <link linkend="functions-datetime-current">below</link>
+ <entry>Time of day; see <xref linkend="functions-datetime-current">
</entry>
<entry></entry>
<entry></entry>
<row>
<entry><function>current_timestamp</function></entry>
<entry><type>timestamp with time zone</type></entry>
- <entry>Date and time; see <link linkend="functions-datetime-current">below</link>
+ <entry>Date and time; see <xref linkend="functions-datetime-current">
</entry>
<entry></entry>
<entry></entry>
<row>
<entry><function>date_trunc</function>(<type>text</type>, <type>timestamp</type>)</entry>
<entry><type>timestamp</type></entry>
- <entry>Truncate to specified precision; see also <link
- linkend="functions-datetime-trunc">below</link>
+ <entry>Truncate to specified precision; see also <xref
+ linkend="functions-datetime-trunc">
</entry>
<entry><literal>date_trunc('hour', timestamp '2001-02-16 20:38:40')</literal></entry>
<entry><literal>2001-02-16 20:00:00+00</literal></entry>
<entry><function>extract</function>(<parameter>field</parameter> from
<type>timestamp</type>)</entry>
<entry><type>double precision</type></entry>
- <entry>Get subfield; see also <link
- linkend="functions-datetime-extract">below</link>
+ <entry>Get subfield; see also <xref
+ linkend="functions-datetime-extract">
</entry>
<entry><literal>extract(hour from timestamp '2001-02-16 20:38:40')</literal></entry>
<entry><literal>20</literal></entry>
<entry><function>extract</function>(<parameter>field</parameter> from
<type>interval</type>)</entry>
<entry><type>double precision</type></entry>
- <entry>Get subfield; see also <link
- linkend="functions-datetime-extract">below</link>
+ <entry>Get subfield; see also <xref
+ linkend="functions-datetime-extract">
</entry>
<entry><literal>extract(month from interval '2 years 3 months')</literal></entry>
<entry><literal>3</literal></entry>
<row>
<entry><function>localtime</function></entry>
<entry><type>time</type></entry>
- <entry>Time of day; see <link linkend="functions-datetime-current">below</link>
+ <entry>Time of day; see <xref linkend="functions-datetime-current">
</entry>
<entry></entry>
<entry></entry>
<row>
<entry><function>localtimestamp</function></entry>
<entry><type>timestamp</type></entry>
- <entry>Date and time; see <link linkend="functions-datetime-current">below</link>
+ <entry>Date and time; see <xref linkend="functions-datetime-current">
</entry>
<entry></entry>
<entry></entry>
<entry><function>now</function>()</entry>
<entry><type>timestamp</type></entry>
<entry>Current date and time (equivalent to
- <function>current_timestamp</function>); see <link
- linkend="functions-datetime-current">below</link>
+ <function>current_timestamp</function>); see <xref
+ linkend="functions-datetime-current">
</entry>
<entry></entry>
<entry></entry>
<row>
<entry><function>timeofday()</function></entry>
<entry><type>text</type></entry>
- <entry>Current date and time; see <link
- linkend="functions-datetime-current">below</link>
+ <entry>Current date and time; see <xref
+ linkend="functions-datetime-current">
</entry>
<entry><literal>timeofday()</literal></entry>
<entry><literal>Wed Feb 21 17:01:13.000126 2001 EST</literal></entry>
</tbody>
</tgroup>
</table>
- </para>
<sect2 id="functions-datetime-extract">
<title><function>EXTRACT</function>, <function>date_part</function></title>
</synopsis>
<para>
- The <function>extract</function> function retrieves sub-fields
+ The <function>extract</function> function retrieves subfields
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>.
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 the result for the century field is simply the year field
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>
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>
<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>
<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>
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>
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>
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>
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 the result for the millennium field is simply the year field
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>
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>
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 13 months');
<lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
</screen>
- </informalexample>
</listitem>
</varlistentry>
<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>
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>
<!--
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>
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>
<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>
</simplelist>
</para>
- <informalexample>
- <para>
+ <para>
+ Examples:
<screen>
SELECT date_trunc('hour', TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>2001-02-16 20:00:00+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>
+ </para>
</sect2>
<sect2 id="functions-datetime-current">
<para>
The following functions are available to obtain the current date and/or
time:
- <synopsis>
+<synopsis>
CURRENT_DATE
CURRENT_TIME
CURRENT_TIMESTAMP
LOCALTIMESTAMP
LOCALTIME ( <replaceable>precision</replaceable> )
LOCALTIMESTAMP ( <replaceable>precision</replaceable> )
- </synopsis>
+</synopsis>
<function>CURRENT_TIME</function>,
<function>CURRENT_TIMESTAMP</function>,
<function>LOCALTIME</function>, and
</para>
</note>
- <informalexample>
- <screen>
+ <para>
+ Some examples:
+<screen>
SELECT CURRENT_TIME;
<computeroutput>14:39:53.662522-05</computeroutput>
SELECT LOCALTIMESTAMP;
<computeroutput>2001-12-23 14:39:53.662522</computeroutput>
</screen>
- </informalexample>
+ </para>
<para>
The function <function>now()</function> is the traditional
<para>
There is also <function>timeofday()</function>, which for historical
reasons returns a text string rather than a <type>timestamp</type> value:
- </para>
-
- <informalexample>
<screen>
SELECT timeofday();
Sat Feb 17 19:07:32.000126 2001 EST
</screen>
- </informalexample>
+ </para>
<para>
It is important to realize that
SELECT now();
SELECT TIMESTAMP 'now';
</programlisting>
+ </para>
+
<note>
<para>
- You do not want to use the third form when specifying a DEFAULT
- value while creating a table. The system will convert <literal>now</literal>
+ You do not want to use the third form when specifying a <literal>DEFAULT</>
+ clause while creating a table. The system will convert <literal>now</literal>
to a <type>timestamp</type> as soon as the constant is parsed, so that when
the default value is needed,
the time of the table creation would be used! The first two
behavior of defaulting to the time of row insertion.
</para>
</note>
- </para>
</sect2>
</sect1>
<sect1 id="functions-geometry">
- <title>Geometric Functions and Operators</title>
+ <title>Geometric Functions and Operators</title>
<para>
The geometric types <type>point</type>, <type>box</type>,
<type>lseg</type>, <type>line</type>, <type>path</type>,
<type>polygon</type>, and <type>circle</type> have a large set of
- native support functions and operators.
+ native support functions and operators, shown in <xref
+ linkend="functions-geometry-op-table">, <xref
+ linkend="functions-geometry-func-table">, and <xref
+ linkend="functions-geometry-conv-table">.
</para>
- <table>
+ <table id="functions-geometry-op-table">
<title>Geometric Operators</title>
<tgroup cols="3">
<thead>
</tgroup>
</table>
- <table>
+
+ <table id="functions-geometry-func-table">
<title>Geometric Functions</title>
<tgroup cols="4">
<thead>
</table>
- <table>
+ <table id="functions-geometry-conv-table">
<title>Geometric Type Conversion Functions</title>
<tgroup cols="4">
<thead>
<para>
It is possible to access the two component numbers of a <type>point</>
- as though it were an array with subscripts 0,1. For example, if
+ as though it were an array with subscripts 0, 1. For example, if
<literal>t.p</> is a <type>point</> column then
<literal>SELECT p[0] FROM t</> retrieves the X coordinate;
<literal>UPDATE t SET p[1] = ...</> changes the Y coordinate.
</sect1>
- <sect1 id="functions-net">
- <title>Network Address Type Functions</title>
+ <sect1 id="functions-net">
+ <title>Network Address Type Functions</title>
+ <para>
+ <xref linkend="cidr-inet-operators-table"> shows the operators
+ available for the <type>inet</type> and <type>cidr</type> types.
+ The operators <literal><<</literal>,
+ <literal><<=</literal>, <literal>>></literal>,
+ <literal>>>=</literal> test for subnet inclusion: they
+ consider only the network parts of the two addresses, ignoring any
+ host part, and determine whether one network part is identical to
+ or a subnet of the other.
+ </para>
<table tocentry="1" id="cidr-inet-operators-table">
<title><type>cidr</type> and <type>inet</type> Operators</title>
</tgroup>
</table>
- <para>
- All of the operators for <type>inet</type> can be applied to
- <type>cidr</type> values as well. The operators
- <literal><<</literal>, <literal><<=</literal>,
- <literal>>></literal>, <literal>>>=</literal>
- test for subnet inclusion: they consider only the network parts
- of the two addresses, ignoring any host part, and determine whether
- one network part is identical to or a subnet of the other.
- </para>
-
+ <para>
+ <xref linkend="cidr-inet-functions-table"> shows the functions
+ available for use with the <type>inet</type> and <type>cidr</type>
+ types. The <function>host()</function>,
+ <function>text()</function>, and <function>abbrev()</function>
+ functions are primarily intended to offer alternative display
+ formats. You can cast a text field to inet using normal casting
+ syntax: <literal>inet(expression)</literal> or
+ <literal>colname::inet</literal>.
+ </para>
- <table tocentry="1" id="cidr-inet-functions">
+ <table tocentry="1" id="cidr-inet-functions-table">
<title><type>cidr</type> and <type>inet</type> Functions</title>
<tgroup cols="5">
<thead>
</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>(),
- <function>text</function>(), and <function>abbrev</function>() functions are primarily
- intended to offer alternative display formats. You can cast a text
- field to inet using normal casting syntax: <literal>inet(expression)</literal> or
- <literal>colname::inet</literal>.
- </para>
+ <para>
+ <xref linkend="macaddr-functions-table"> shows the functions
+ available for use with the <type>mac</type> type. The function
+ <function>trunc</function>(<type>macaddr</type>) 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</filename> in the source distribution
+ contains some utilities to create and maintain such an association
+ table.
+ </para>
- <table tocentry="1" id="macaddr-functions">
+ <table tocentry="1" id="macaddr-functions-table">
<title><type>macaddr</type> Functions</title>
<tgroup cols="5">
<thead>
</tgroup>
</table>
- <para>
- The function <function>trunc</function>(<type>macaddr</type>) 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</filename> in the source distribution contains some
- utilities to create and maintain such an association table.
- </para>
-
<para>
The <type>macaddr</type> type also supports the standard relational
operators (<literal>></literal>, <literal><=</literal>, etc.) for
<primary>setval</primary>
</indexterm>
- <table>
+ <para>
+ This section describes <productname>PostgreSQL</productname>'s functions
+ for operating on <firstterm>sequence objects</firstterm>.
+ Sequence objects (also called sequence generators or
+ just sequences) are special single-row tables created with
+ <command>CREATE SEQUENCE</command>. A sequence object is usually used to
+ generate unique identifiers for rows of a table. The sequence functions,
+ listed in <xref linkend="functions-sequence-table">,
+ provide simple, multiuser-safe methods for obtaining successive
+ sequence values from sequence objects.
+ </para>
+
+ <table id="functions-sequence-table">
<title>Sequence Functions</title>
<tgroup cols="3">
<thead>
</tgroup>
</table>
- <para>
- This section describes <productname>PostgreSQL</productname>'s functions
- for operating on <firstterm>sequence objects</firstterm>.
- Sequence objects (also called sequence generators or
- just sequences) are special single-row tables created with
- <command>CREATE SEQUENCE</command>. A sequence object is usually used to
- generate unique identifiers for rows of a table. The sequence functions
- provide simple, multiuser-safe methods for obtaining successive
- sequence values from sequence objects.
- </para>
-
<para>
For largely historical reasons, the sequence to be operated on by
a sequence-function call is specified by a text-string argument.
names, the sequence functions convert their argument to lower case
unless the string is double-quoted. Thus
<programlisting>
-nextval('foo') <lineannotation>operates on sequence </><literal>foo</literal>
-nextval('FOO') <lineannotation>operates on sequence </><literal>foo</literal>
-nextval('"Foo"') <lineannotation>operates on sequence </><literal>Foo</literal>
+nextval('foo') <lineannotation>operates on sequence <literal>foo</literal></>
+nextval('FOO') <lineannotation>operates on sequence <literal>foo</literal></>
+nextval('"Foo"') <lineannotation>operates on sequence <literal>Foo</literal></>
</programlisting>
The sequence name can be schema-qualified if necessary:
<programlisting>
-nextval('myschema.foo') <lineannotation>operates on </><literal>myschema.foo</literal>
-nextval('"myschema".foo') <lineannotation>same as above</lineannotation>
-nextval('foo') <lineannotation>searches search path for
- </><literal>foo</literal>
+nextval('myschema.foo') <lineannotation>operates on <literal>myschema.foo</literal></>
+nextval('"myschema".foo') <lineannotation>same as above</lineannotation>
+nextval('foo') <lineannotation>searches search path for <literal>foo</literal></>
</programlisting>
Of course, the text argument can be the result of an expression,
not only a simple literal, which is occasionally useful.
<listitem>
<para>
Advance the sequence object to its next value and return that
- value. This is done atomically: even if multiple server processes
+ value. This is done atomically: even if multiple sessions
execute <function>nextval</function> concurrently, each will safely receive
a distinct sequence value.
</para>
<listitem>
<para>
Return the value most recently obtained by <function>nextval</function>
- for this sequence in the current server process. (An error is
+ for this sequence in the current session. (An error is
reported if <function>nextval</function> has never been called for this
- sequence in this process.) Notice that because this is returning
- a process-local value, it gives a predictable answer even if other
- server processes are executing <function>nextval</function> meanwhile.
+ sequence in this session.) Notice that because this is returning
+ a session-local value, it gives a predictable answer even if other
+ sessions are executing <function>nextval</function> meanwhile.
</para>
</listitem>
</varlistentry>
the next <function>nextval</function> will return exactly the specified
value, and sequence advancement commences with the following
<function>nextval</function>. For example,
- </para>
- <informalexample>
<screen>
-SELECT setval('foo', 42); <lineannotation>Next nextval() will return 43</lineannotation>
+SELECT setval('foo', 42); <lineannotation>Next <function>nextval()</> will return 43</lineannotation>
SELECT setval('foo', 42, true); <lineannotation>Same as above</lineannotation>
-SELECT setval('foo', 42, false); <lineannotation>Next nextval() will return 42</lineannotation>
+SELECT setval('foo', 42, false); <lineannotation>Next <function>nextval()</> will return 42</lineannotation>
</screen>
- </informalexample>
- <para>
The result returned by <function>setval</function> is just the value of its
second argument.
</para>
</para>
</tip>
- <bridgehead renderas="sect2"><literal>CASE</></bridgehead>
+ <sect2>
+ <title>CASE</title>
<synopsis>
CASE WHEN <replaceable>condition</replaceable> THEN <replaceable>result</replaceable>
omitted and no condition matches, the result is null.
</para>
- <informalexample>
<para>
An example:
<screen>
</computeroutput>
</screen>
</para>
- </informalexample>
<para>
The data types of all the <replaceable>result</replaceable>
to the <function>switch</function> statement in C.
</para>
- <informalexample>
<para>
The example above can be written using the simple
<token>CASE</token> syntax:
</computeroutput>
</screen>
</para>
- </informalexample>
+ </sect2>
- <bridgehead renderas="sect2"><literal>COALESCE</></bridgehead>
+ <sect2>
+ <title>COALESCE</title>
<synopsis>
-<function>COALESCE</function>(<replaceable>value</replaceable>
-<optional>, ...</optional>)
+<function>COALESCE</function>(<replaceable>value</replaceable> <optional>, ...</optional>)
</synopsis>
<para>
SELECT COALESCE(description, short_description, '(none)') ...
</programlisting>
</para>
+ </sect2>
- <bridgehead renderas="sect2"><literal>NULLIF</></bridgehead>
+ <sect2>
+ <title>NULLIF</title>
<indexterm>
<primary>nullif</primary>
</indexterm>
<synopsis>
-<function>NULLIF</function>(<replaceable>value1</replaceable>,
- <replaceable>value2</replaceable>)
+<function>NULLIF</function>(<replaceable>value1</replaceable>, <replaceable>value2</replaceable>)
</synopsis>
<para>
refers to <token>CASE</token>.
</para>
</tip>
+ </sect2>
</sect1>
- <sect1 id="functions-misc">
- <title>Miscellaneous Functions</title>
+ <sect1 id="functions-misc">
+ <title>Miscellaneous Functions</title>
- <table>
+ <para>
+ <xref linkend="functions-misc-session-table"> shows several
+ functions that extract session and system information.
+ </para>
+
+ <table id="functions-misc-session-table">
<title>Session Information Functions</title>
<tgroup cols="3">
<thead>
</thead>
<tbody>
+ <row>
+ <entry><function>current_database()</function></entry>
+ <entry><type>name</type></entry>
+ <entry>name of current database</entry>
+ </row>
+
+ <row>
+ <entry><function>current_schema()</function></entry>
+ <entry><type>name</type></entry>
+ <entry>name of current schema</entry>
+ </row>
+
+ <row>
+ <entry><function>current_schemas(boolean)</function></entry>
+ <entry><type>name[]</type></entry>
+ <entry>names of schemas in search path optionally including implicit schemas</entry>
+ </row>
+
<row>
<entry><function>current_user</function></entry>
<entry><type>name</type></entry>
<entry>user name of current execution context</entry>
</row>
+
<row>
<entry><function>session_user</function></entry>
<entry><type>name</type></entry>
<entry>session user name</entry>
</row>
+
<row>
<entry><function>user</function></entry>
<entry><type>name</type></entry>
<entry>equivalent to <function>current_user</function></entry>
</row>
+
<row>
- <entry><function>current_schema()</function></entry>
- <entry><type>name</type></entry>
- <entry>name of current schema</entry>
- </row>
- <row>
- <entry><function>current_schemas(boolean)</function></entry>
- <entry><type>name[]</type></entry>
- <entry>names of schemas in search path optionally including implicit schemas</entry>
- </row>
- <row>
- <entry><function>current_database()</function></entry>
- <entry><type>name</type></entry>
- <entry>name of current database</entry>
+ <entry><function>version</function></entry>
+ <entry><type>text</type></entry>
+ <entry>PostgreSQL version information</entry>
</row>
</tbody>
</tgroup>
</para>
</note>
- <note>
- <title>Deprecated</title>
- <para>
- The function <function>getpgusername()</function> is an obsolete equivalent
- of <function>current_user</function>.
- </para>
- </note>
-
<para>
<function>current_schema</function> returns the name of the schema that is
at the front of the search path (or a null value if the search path is
</command>
</para>
- <table>
- <title>System Information Functions</title>
- <tgroup cols="3">
- <thead>
- <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
- </thead>
-
- <tbody>
- <row>
- <entry><function>version</function></entry>
- <entry><type>text</type></entry>
- <entry>PostgreSQL version information</entry>
- </row>
- </tbody>
- </tgroup>
- </table>
-
<indexterm zone="functions-misc">
<primary>version</primary>
</indexterm>
server's version.
</para>
- <table>
+ <para>
+ <xref linkend="functions-misc-set-table"> shows the functions
+ available to query and alter run-time configuration parameters.
+ </para>
+
+ <table id="functions-misc-set-table">
<title>Configuration Settings Information Functions</title>
<tgroup cols="3">
<thead>
</programlisting>
</para>
- <table>
+ <para>
+ <xref linkend="functions-misc-access-table"> lists functions that
+ allow the user to query object access privileges programmatically.
+ See <xref linkend="ddl-priv"> for more information about
+ privileges.
+ </para>
+
+ <table id="functions-misc-access-table">
<title>Access Privilege Inquiry Functions</title>
<tgroup cols="3">
<thead>
<literal>USAGE</literal>.
</para>
- <table>
+ <para>
+ <xref linkend="functions-misc-schema-table"> shows functions that
+ determine whether a certain object is <firstterm>visible</> in the
+ current schema search path. A table is said to be visible if its
+ containing schema is in the search path and no table of the same
+ name appears earlier in the search path. This is equivalent to the
+ statement that the table can be referenced by name without explicit
+ schema qualification. For example, to list the names of all
+ visible tables:
+<programlisting>
+SELECT relname FROM pg_class WHERE pg_table_is_visible(oid);
+</programlisting>
+ </para>
+
+ <table id="functions-misc-schema-table">
<title>Schema Visibility Inquiry Functions</title>
<tgroup cols="3">
<thead>
</indexterm>
<para>
- <function>pg_table_is_visible</function> checks whether a table
- (or view, or any other kind of <structname>pg_class</> entry) is
- <firstterm>visible</> in the current schema search path. A table
- is said to be visible if its containing schema is in the search path
- and no table of the same name appears earlier in the search path.
- This is equivalent to the statement that the table can be referenced
- by name without explicit schema qualification.
- For example, to list the names of all visible tables:
-<programlisting>
-SELECT relname FROM pg_class WHERE pg_table_is_visible(oid);
-</programlisting>
- </para>
-
- <para>
- <function>pg_type_is_visible</function>,
- <function>pg_function_is_visible</function>,
- <function>pg_operator_is_visible</function>, and
- <function>pg_opclass_is_visible</function> perform the same sort of
- visibility check for types, functions, operators, and operator classes,
- respectively. For functions and operators, an object in the search path
- is visible if there is no object of the same name <emphasis>and argument
- data type(s)</> earlier in the path. For operator classes,
- both name and associated index access method are considered.
+ <function>pg_table_is_visible</function> performs the check for
+ tables (or views, or any other kind of <literal>pg_class</> entry).
+ <function>pg_type_is_visible</function>,
+ <function>pg_function_is_visible</function>,
+ <function>pg_operator_is_visible</function>, and
+ <function>pg_opclass_is_visible</function> perform the same sort of
+ visibility check for types, functions, operators, and operator
+ classes, respectively. For functions and operators, an object in
+ the search path is visible if there is no object of the same name
+ <emphasis>and argument data type(s)</> earlier in the path. For
+ operator classes, both name and associated index access method are
+ considered.
</para>
<para>
this way --- if the name can be recognized at all, it must be visible.
</para>
- <table>
+ <indexterm zone="functions-misc">
+ <primary>pg_get_viewdef</primary>
+ </indexterm>
+
+ <indexterm zone="functions-misc">
+ <primary>pg_get_ruledef</primary>
+ </indexterm>
+
+ <indexterm zone="functions-misc">
+ <primary>pg_get_indexdef</primary>
+ </indexterm>
+
+ <indexterm zone="functions-misc">
+ <primary>pg_get_constraintdef</primary>
+ </indexterm>
+
+ <indexterm zone="functions-misc">
+ <primary>pg_get_userbyid</primary>
+ </indexterm>
+
+ <para>
+ <xref linkend="functions-misc-catalog-table"> lists functions that
+ extract information from the system catalogs.
+ <function>pg_get_viewdef()</function>,
+ <function>pg_get_ruledef()</function>,
+ <function>pg_get_indexdef()</function>, and
+ <function>pg_get_constraintdef()</function> respectively
+ reconstruct the creating command for a view, rule, index, or
+ constraint. (Note that this is a decompiled reconstruction, not
+ the verbatim text of the command.) At present
+ <function>pg_get_constraintdef()</function> only works for
+ foreign-key constraints. <function>pg_get_userbyid()</function>
+ extracts a user's name given a <structfield>usesysid</structfield>
+ value.
+ </para>
+
+ <table id="functions-misc-catalog-table">
<title>Catalog Information Functions</title>
<tgroup cols="3">
<thead>
<row>
<entry><function>pg_get_viewdef</function>(<parameter>viewname</parameter>)</entry>
<entry><type>text</type></entry>
- <entry>Get CREATE VIEW command for view (<emphasis>deprecated</emphasis>)</entry>
+ <entry>Get <command>CREATE VIEW</> command for view (<emphasis>deprecated</emphasis>)</entry>
</row>
<row>
<entry><function>pg_get_viewdef</function>(<parameter>viewOID</parameter>)</entry>
<entry><type>text</type></entry>
- <entry>Get CREATE VIEW command for view</entry>
+ <entry>Get <command>CREATE VIEW</> command for view</entry>
</row>
<row>
<entry><function>pg_get_ruledef</function>(<parameter>ruleOID</parameter>)</entry>
<entry><type>text</type></entry>
- <entry>Get CREATE RULE command for rule</entry>
+ <entry>Get <command>CREATE RULE</> command for rule</entry>
</row>
<row>
<entry><function>pg_get_indexdef</function>(<parameter>indexOID</parameter>)</entry>
<entry><type>text</type></entry>
- <entry>Get CREATE INDEX command for index</entry>
+ <entry>Get <command>CREATE INDEX</> command for index</entry>
</row>
<row>
<entry><function>pg_get_constraintdef</function>(<parameter>constraintOID</parameter>)</entry>
<row>
<entry><function>pg_get_userbyid</function>(<parameter>userid</parameter>)</entry>
<entry><type>name</type></entry>
- <entry>Get user name given ID</entry>
+ <entry>Get user name with given ID</entry>
</row>
</tbody>
</tgroup>
</table>
<indexterm zone="functions-misc">
- <primary>pg_get_viewdef</primary>
- </indexterm>
-
- <indexterm zone="functions-misc">
- <primary>pg_get_ruledef</primary>
- </indexterm>
-
- <indexterm zone="functions-misc">
- <primary>pg_get_indexdef</primary>
- </indexterm>
-
- <indexterm zone="functions-misc">
- <primary>pg_get_constraintdef</primary>
+ <primary>obj_description</primary>
</indexterm>
<indexterm zone="functions-misc">
- <primary>pg_get_userbyid</primary>
+ <primary>col_description</primary>
</indexterm>
<para>
- These functions extract information from the system catalogs.
- <function>pg_get_viewdef()</function>,
- <function>pg_get_ruledef()</function>,
- <function>pg_get_indexdef()</function>, and
- <function>pg_get_constraintdef()</function> respectively reconstruct the
- creating command for a view, rule, index, or constraint.
- (Note that this is a decompiled
- reconstruction, not the verbatim text of the command.)
- At present <function>pg_get_constraintdef()</function> only works for
- foreign-key constraints.
- <function>pg_get_userbyid()</function> extracts a user's name given a
- <structfield>usesysid</structfield> value.
+ The function shown in <xref
+ linkend="functions-misc-comment-table"> extract comments
+ previously stored with the <command>COMMENT</command> command. A
+ null value is returned if no comment can be found matching the
+ specified parameters.
</para>
- <table>
+ <table id="functions-misc-comment-table">
<title>Comment Information Functions</title>
<tgroup cols="3">
<thead>
</tgroup>
</table>
- <indexterm zone="functions-misc">
- <primary>obj_description</primary>
- </indexterm>
-
- <indexterm zone="functions-misc">
- <primary>col_description</primary>
- </indexterm>
-
- <para>
- These functions extract comments previously stored with the
- <command>COMMENT</command> command. A null value is returned if
- no comment can be found matching the specified parameters.
- </para>
-
<para>
The two-parameter form of <function>obj_description()</function> returns the
comment for a database object specified by its OID and the name of the
<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.
+ value from a set of input values. <xref
+ linkend="functions-aggregate-table"> show the built-in aggregate
+ functions. The special syntax considerations for aggregate
+ functions are explained in <xref linkend="syntax-aggregates">.
+ Consult the &cite-tutorial; for additional introductory
+ information.
</para>
- <table tocentry="1">
+ <table id="functions-aggregate-table">
<title>Aggregate Functions</title>
- <tgroup cols="3">
+ <tgroup cols="5">
<thead>
<row>
<entry>Function</entry>
+ <entry>Argument Type</entry>
+ <entry>Return Type</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>
<indexterm>
<primary>average</primary>
<secondary>function</secondary>
</indexterm>
- Finding the average value is available on the following data
- types: <type>smallint</type>, <type>integer</type>,
+ <function>avg(<replaceable class="parameter">expression</replaceable>)</function>
+ </entry>
+ <entry>
+ <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.
+ precision</type>, <type>numeric</type>, or <type>interval</type>.
+ </entry>
+ <entry>
+ <type>numeric</type> for any integer type argument,
+ <type>double precision</type> for a floating-point argument,
+ otherwise the same as the argument data type
</entry>
+ <entry>the average (arithmetic mean) of all input values</entry>
</row>
<row>
- <entry><function>count</function>(*)</entry>
+ <entry><function>count(*)</function></entry>
+ <entry></entry>
+ <entry><type>bigint</type></entry>
<entry>number of input values</entry>
- <entry>The return value is of type <type>bigint</type>.</entry>
</row>
<row>
- <entry><function>count</function>(<replaceable class="parameter">expression</replaceable>)</entry>
+ <entry><function>count(<replaceable class="parameter">expression</replaceable>)</function></entry>
+ <entry>any</entry>
+ <entry><type>bigint</type></entry>
<entry>
- Counts the input values for which the value of <replaceable
- class="parameter">expression</replaceable> is not null.
+ number of input values for which the value of <replaceable
+ class="parameter">expression</replaceable> is not null
</entry>
- <entry>The return value is of type <type>bigint</type>.</entry>
</row>
<row>
- <entry><function>max</function>(<replaceable class="parameter">expression</replaceable>)</entry>
- <entry>the maximum value of <replaceable class="parameter">expression</replaceable> across all input values</entry>
+ <entry><function>max(<replaceable class="parameter">expression</replaceable>)</function></entry>
+ <entry>any numeric, string, or date/time type</entry>
+ <entry>same as argument type</entry>
<entry>
- Available for all numeric, string, and date/time types. The
- result has the same type as the input expression.
+ maximum value of <replaceable
+ class="parameter">expression</replaceable> across all input
+ values
</entry>
</row>
<row>
- <entry><function>min</function>(<replaceable class="parameter">expression</replaceable>)</entry>
- <entry>the minimum value of <replaceable class="parameter">expression</replaceable> across all input values</entry>
+ <entry><function>min(<replaceable class="parameter">expression</replaceable>)</function></entry>
+ <entry>any numeric, string, or date/time type</entry>
+ <entry>same as argument type</entry>
<entry>
- Available for all numeric, string, and date/time types. The
- result has the same type as the input expression.
+ minimum value of <replaceable
+ class="parameter">expression</replaceable> across all input
+ values
</entry>
</row>
<row>
- <entry><function>stddev</function>(<replaceable
- class="parameter">expression</replaceable>)</entry>
- <entry>the sample standard deviation of the input values</entry>
<entry>
<indexterm>
<primary>standard deviation</primary>
</indexterm>
- Finding the standard deviation is available on the following
- data types: <type>smallint</type>, <type>integer</type>,
+ <function>stddev(<replaceable class="parameter">expression</replaceable>)</function>
+ </entry>
+ <entry>
+ <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,
+ precision</type>, or <type>numeric</type>.
+ </entry>
+ <entry>
+ <type>double precision</type> for floating-point arguments,
otherwise <type>numeric</type>.
</entry>
+ <entry>sample standard deviation of the input values</entry>
</row>
<row>
- <entry><function>sum</function>(<replaceable class="parameter">expression</replaceable>)</entry>
- <entry>sum of <replaceable class="parameter">expression</replaceable> across all input values</entry>
+ <entry><function>sum(<replaceable class="parameter">expression</replaceable>)</function></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>bigint</type> for <type>smallint</type>
- or <type>integer</type> input, <type>numeric</type> for
- <type>bigint</type>
- input, <type>double precision</type> for floating-point input,
- otherwise the same as the input data type.
+ precision</type>, <type>numeric</type>, or
+ <type>interval</type>
+ </entry>
+ <entry>
+ <type>bigint</type> for <type>smallint</type> or
+ <type>integer</type> arguments, <type>numeric</type> for
+ <type>bigint</type> arguments, <type>double precision</type>
+ for floating-point arguments, otherwise the same as the
+ argument data type
</entry>
+ <entry>sum of <replaceable class="parameter">expression</replaceable> across all input values</entry>
</row>
<row>
- <entry><function>variance</function>(<replaceable
- class="parameter">expression</replaceable>)</entry>
- <entry>the sample variance of the input values</entry>
<entry>
<indexterm>
<primary>variance</primary>
</indexterm>
- The variance is the square of the standard deviation. The
- supported data types and result types are the same as for
- standard deviation.
+ <function>variance</function>(<replaceable class="parameter">expression</replaceable>)
+ </entry>
+ <entry>
+ <type>smallint</type>, <type>integer</type>,
+ <type>bigint</type>, <type>real</type>, <type>double
+ precision</type>, or <type>numeric</type>.
+ </entry>
+ <entry>
+ <type>double precision</type> for floating-point arguments,
+ otherwise <type>numeric</type>.
</entry>
+ <entry>sample variance of the input values (square of the sample standard deviation)</entry>
</row>
</tbody>
</table>
<para>
- It should be noted that except for <function>COUNT</function>,
+ It should be noted that except for <function>count</function>,
these functions return a null value when no rows are selected. In
- particular, <function>SUM</function> of no rows returns null, not
- zero as one might expect. <function>COALESCE</function> may be
+ particular, <function>sum</function> of no rows returns null, not
+ zero as one might expect. The function <function>coalesce</function> may be
used to substitute zero for null when necessary.
</para>
Boolean (true/false) results.
</para>
- <bridgehead renderas="sect2">EXISTS</bridgehead>
+ <sect2>
+ <title>EXISTS</title>
<synopsis>
EXISTS ( <replaceable>subquery</replaceable> )
</synopsis>
<para>
- The argument of <token>EXISTS</token> is an arbitrary SELECT statement,
+ The argument of <token>EXISTS</token> is an arbitrary <command>SELECT</> statement,
or <firstterm>subquery</firstterm>. The
subquery is evaluated to determine whether it returns any rows.
If it returns at least one row, the result of <token>EXISTS</token> is
- TRUE; if the subquery returns no rows, the result of <token>EXISTS</token>
- is FALSE.
+ <quote>true</>; if the subquery returns no rows, the result of <token>EXISTS</token>
+ is <quote>false</>.
</para>
<para>
<para>
The subquery will generally only be executed far enough to determine
whether at least one row is returned, not all the way to completion.
- It is unwise to write a subquery that has any side-effects (such as
- calling sequence functions); whether the side-effects occur or not
+ It is unwise to write a subquery that has any side effects (such as
+ calling sequence functions); whether the side effects occur or not
may be difficult to predict.
</para>
Since the result depends only on whether any rows are returned,
and not on the contents of those rows, the output list of the
subquery is normally uninteresting. A common coding convention is
- to write all EXISTS tests in the form
+ to write all <literal>EXISTS</> tests in the form
<literal>EXISTS(SELECT 1 WHERE ...)</literal>. There are exceptions to
this rule however, such as subqueries that use <token>INTERSECT</token>.
</para>
<para>
- This simple example is like an inner join on col2, but it produces at
- most one output row for each tab1 row, even if there are multiple matching
- tab2 rows:
+ This simple example is like an inner join on <literal>col2</>, but
+ it produces at most one output row for each <literal>tab1</> row,
+ even if there are multiple matching <literal>tab2</> rows:
<screen>
SELECT col1 FROM tab1
WHERE EXISTS(SELECT 1 FROM tab2 WHERE col2 = tab1.col2);
</screen>
</para>
+ </sect2>
- <bridgehead renderas="sect2">IN (scalar form)</bridgehead>
+ <sect2>
+ <title>IN (scalar form)</title>
<synopsis>
-<replaceable>expression</replaceable> IN
- <replaceable>value</replaceable><optional>, ...</optional>)
+<replaceable>expression</replaceable> IN (<replaceable>value</replaceable><optional>, ...</optional>)
</synopsis>
<para>
The right-hand side of this form of <token>IN</token> is a parenthesized list
- of scalar expressions. The result is TRUE if the left-hand expression's
+ of scalar expressions. The result is <quote>true</> if the left-hand expression's
result is equal to any of the right-hand expressions. This is a shorthand
notation for
...
</synopsis>
- Note that if the left-hand expression yields NULL, or if there are
+ Note that if the left-hand expression yields null, or if there are
no equal right-hand values and at least one right-hand expression yields
- NULL, the result of the <token>IN</token> construct will be NULL, not FALSE.
+ null, the result of the <token>IN</token> construct will be null, not false.
This is in accordance with SQL's normal rules for Boolean combinations
- of NULL values.
+ of null values.
</para>
<note>
seems best to document it in the same place as subquery <token>IN</token>.
</para>
</note>
+ </sect2>
- <bridgehead renderas="sect2">IN (subquery form)</bridgehead>
+ <sect2>
+ <title>IN (subquery form)</title>
<synopsis>
<replaceable>expression</replaceable> IN (<replaceable>subquery</replaceable>)
The right-hand side of this form of <token>IN</token> is a parenthesized
subquery, which must return exactly one column. The left-hand expression
is evaluated and compared to each row of the subquery result.
- The result of <token>IN</token> is TRUE if any equal subquery row is found.
- The result is FALSE if no equal row is found (including the special
+ The result of <token>IN</token> is <quote>true</> if any equal subquery row is found.
+ The result is <quote>false</> if no equal row is found (including the special
case where the subquery returns no rows).
</para>
<para>
- Note that if the left-hand expression yields NULL, or if there are
+ Note that if the left-hand expression yields null, or if there are
no equal right-hand values and at least one right-hand row yields
- NULL, the result of the <token>IN</token> construct will be NULL, not FALSE.
+ null, the result of the <token>IN</token> construct will be null, not false.
This is in accordance with SQL's normal rules for Boolean combinations
- of NULL values.
+ of null values.
</para>
<para>
</para>
<synopsis>
-(<replaceable>expression</replaceable>,
-<replaceable>expres</replaceable><optional>,</optional>)
- IN (<replaceable>subquery</replaceable>)
+(<replaceable>expression</replaceable> <optional>, <replaceable>expression</replaceable> ...</optional>) IN (<replaceable>subquery</replaceable>)
</synopsis>
<para>
subquery, which must return exactly as many columns as there are
expressions in the left-hand list. The left-hand expressions are
evaluated and compared row-wise to each row of the subquery result.
- The result of <token>IN</token> is TRUE if any equal subquery row is found.
- The result is FALSE if no equal row is found (including the special
+ The result of <token>IN</token> is <quote>true</> if any equal subquery row is found.
+ The result is <quote>false</> if no equal row is found (including the special
case where the subquery returns no rows).
</para>
the normal rules of SQL Boolean expressions. Two rows are considered
equal if all their corresponding members are non-null and equal; the rows
are unequal if any corresponding members are non-null and unequal;
- otherwise the result of that row comparison is unknown (NULL).
- If all the row results are either unequal or NULL, with at least one NULL,
- then the result of <token>IN</token> is NULL.
+ otherwise the result of that row comparison is unknown (null).
+ If all the row results are either unequal or null, with at least one null,
+ then the result of <token>IN</token> is null.
</para>
+ </sect2>
- <bridgehead renderas="sect2">NOT IN (scalar form)</bridgehead>
+ <sect2>
+ <title>NOT IN (scalar form)</title>
<synopsis>
-<replaceable>expression</replaceable> NOT IN
- <replaceable>value</replaceable><optional>, ...</optional>)
+<replaceable>expression</replaceable> NOT IN (<replaceable>value</replaceable><optional>, ...</optional>)
</synopsis>
<para>
The right-hand side of this form of <token>NOT IN</token> is a parenthesized list
- of scalar expressions. The result is TRUE if the left-hand expression's
+ of scalar expressions. The result is <quote>true</quote> if the left-hand expression's
result is unequal to all of the right-hand expressions. This is a shorthand
notation for
...
</synopsis>
- Note that if the left-hand expression yields NULL, or if there are
+ Note that if the left-hand expression yields null, or if there are
no equal right-hand values and at least one right-hand expression yields
- NULL, the result of the <token>NOT IN</token> construct will be NULL, not TRUE
+ null, the result of the <token>NOT IN</token> construct will be null, not true
as one might naively expect.
This is in accordance with SQL's normal rules for Boolean combinations
- of NULL values.
+ of null values.
</para>
<tip>
It's best to express your condition positively if possible.
</para>
</tip>
+ </sect2>
- <bridgehead renderas="sect2">NOT IN (subquery form)</bridgehead>
+ <sect2>
+ <title>NOT IN (subquery form)</title>
<synopsis>
<replaceable>expression</replaceable> NOT IN (<replaceable>subquery</replaceable>)
The right-hand side of this form of <token>NOT IN</token> is a parenthesized
subquery, which must return exactly one column. The left-hand expression
is evaluated and compared to each row of the subquery result.
- The result of <token>NOT IN</token> is TRUE if only unequal subquery rows
+ The result of <token>NOT IN</token> is <quote>true</> if only unequal subquery rows
are found (including the special case where the subquery returns no rows).
- The result is FALSE if any equal row is found.
+ The result is <quote>false</> if any equal row is found.
</para>
<para>
- Note that if the left-hand expression yields NULL, or if there are
+ Note that if the left-hand expression yields null, or if there are
no equal right-hand values and at least one right-hand row yields
- NULL, the result of the <token>NOT IN</token> construct will be NULL, not TRUE.
+ null, the result of the <token>NOT IN</token> construct will be null, not true.
This is in accordance with SQL's normal rules for Boolean combinations
- of NULL values.
+ of null values.
</para>
<para>
</para>
<synopsis>
-(<replaceable>expression</replaceable>,
-<replaceable>expres</replaceable><optional>,</optional>)
- NOT IN (<replaceable>subquery</replaceable>)
+(<replaceable>expression</replaceable> <optional>, <replaceable>expression</replaceable> ...</optional>) NOT IN (<replaceable>subquery</replaceable>)
</synopsis>
<para>
subquery, which must return exactly as many columns as there are
expressions in the left-hand list. The left-hand expressions are
evaluated and compared row-wise to each row of the subquery result.
- The result of <token>NOT IN</token> is TRUE if only unequal subquery rows
+ The result of <token>NOT IN</token> is <quote>true</> if only unequal subquery rows
are found (including the special case where the subquery returns no rows).
- The result is FALSE if any equal row is found.
+ The result is <quote>false</> if any equal row is found.
</para>
<para>
the normal rules of SQL Boolean expressions. Two rows are considered
equal if all their corresponding members are non-null and equal; the rows
are unequal if any corresponding members are non-null and unequal;
- otherwise the result of that row comparison is unknown (NULL).
- If all the row results are either unequal or NULL, with at least one NULL,
- then the result of <token>NOT IN</token> is NULL.
+ otherwise the result of that row comparison is unknown (null).
+ If all the row results are either unequal or null, with at least one null,
+ then the result of <token>NOT IN</token> is null.
</para>
+ </sect2>
- <bridgehead renderas="sect2">ANY</bridgehead>
+ <sect2>
+ <title>ANY/SOME</title>
<synopsis>
-<replaceable>expression</replaceable>
-<replaceable>oper</replaceable> ANY (<replaceable>subquery</replaceable>)
-<replaceable>expression</replaceable>
-<replaceable>oper</replaceable> SOME (<replaceable>subquery</replaceable>)
+<replaceable>expression</replaceable> <replaceable>operator</replaceable> ANY (<replaceable>subquery</replaceable>)
+<replaceable>expression</replaceable> <replaceable>operator</replaceable> SOME (<replaceable>subquery</replaceable>)
</synopsis>
<para>
is evaluated and compared to each row of the subquery result using the
given <replaceable>operator</replaceable>, which must yield a Boolean
result.
- The result of <token>ANY</token> is TRUE if any true result is obtained.
- The result is FALSE if no true result is found (including the special
+ The result of <token>ANY</token> is <quote>true</> if any true result is obtained.
+ The result is <quote>false</> if no true result is found (including the special
case where the subquery returns no rows).
</para>
<para>
Note that if there are no successes and at least one right-hand row yields
- NULL for the operator's result, the result of the <token>ANY</token> construct
- will be NULL, not FALSE.
+ null for the operator's result, the result of the <token>ANY</token> construct
+ will be null, not false.
This is in accordance with SQL's normal rules for Boolean combinations
- of NULL values.
+ of null values.
</para>
<para>
</para>
<synopsis>
-(<replaceable>expression</replaceable>,
-<replaceable>expres</replaceable><optional>,</optional>optiona<replaceable></replaceable> ANY (<replaceable>subquery</replaceable>)
-(<replaceable>expression</replaceable>,
-<replaceable>expres</replaceable><optional>,</optional>optiona<replaceable></replaceable> SOME (<replaceable>subquery</replaceable>)
+(<replaceable>expression</replaceable> <optional>, <replaceable>expression</replaceable> ...</optional>) <replaceable>operator</> ANY (<replaceable>subquery</replaceable>)
+(<replaceable>expression</replaceable> <optional>, <replaceable>expression</replaceable> ...</optional>) <replaceable>operator</> SOME (<replaceable>subquery</replaceable>)
</synopsis>
<para>
using the given <replaceable>operator</replaceable>. Presently,
only <literal>=</literal> and <literal><></literal> operators are allowed
in row-wise <token>ANY</token> queries.
- The result of <token>ANY</token> is TRUE if any equal or unequal row is
+ The result of <token>ANY</token> is <quote>true</> if any equal or unequal row is
found, respectively.
- The result is FALSE if no such row is found (including the special
+ The result is <quote>false</> if no such row is found (including the special
case where the subquery returns no rows).
</para>
the normal rules of SQL Boolean expressions. Two rows are considered
equal if all their corresponding members are non-null and equal; the rows
are unequal if any corresponding members are non-null and unequal;
- otherwise the result of that row comparison is unknown (NULL).
- If there is at least one NULL row result, then the result of <token>ANY</token>
- cannot be FALSE; it will be TRUE or NULL.
+ otherwise the result of that row comparison is unknown (null).
+ If there is at least one null row result, then the result of <token>ANY</token>
+ cannot be false; it will be true or null.
</para>
+ </sect2>
- <bridgehead renderas="sect2">ALL</bridgehead>
+ <sect2>
+ <title>ALL</title>
<synopsis>
-<replaceable>expression</replaceable>
-<replaceable>oper</replaceable> ALL (<replaceable>subquery</replaceable>)
+<replaceable>expression</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>subquery</replaceable>)
</synopsis>
<para>
is evaluated and compared to each row of the subquery result using the
given <replaceable>operator</replaceable>, which must yield a Boolean
result.
- The result of <token>ALL</token> is TRUE if all rows yield TRUE
+ The result of <token>ALL</token> is <quote>true</> if all rows yield true
(including the special case where the subquery returns no rows).
- The result is FALSE if any false result is found.
+ The result is <quote>false</> if any false result is found.
</para>
<para>
<para>
Note that if there are no failures but at least one right-hand row yields
- NULL for the operator's result, the result of the <token>ALL</token> construct
- will be NULL, not TRUE.
+ null for the operator's result, the result of the <token>ALL</token> construct
+ will be null, not true.
This is in accordance with SQL's normal rules for Boolean combinations
- of NULL values.
+ of null values.
</para>
<para>
</para>
<synopsis>
-(<replaceable>expression</replaceable>, <replaceable>expression</replaceable><optional>, ...</optional>) <replaceable>operator</replaceable> ALL (<replaceable>subquery</replaceable>)
+(<replaceable>expression</replaceable> <optional>, <replaceable>expression</replaceable> ...</optional>) <replaceable>operator</replaceable> ALL (<replaceable>subquery</replaceable>)
</synopsis>
<para>
using the given <replaceable>operator</replaceable>. Presently,
only <literal>=</literal> and <literal><></literal> operators are allowed
in row-wise <token>ALL</token> queries.
- The result of <token>ALL</token> is TRUE if all subquery rows are equal
+ The result of <token>ALL</token> is <quote>true</> if all subquery rows are equal
or unequal, respectively (including the special
case where the subquery returns no rows).
- The result is FALSE if any row is found to be unequal or equal,
+ The result is <quote>false</> if any row is found to be unequal or equal,
respectively.
</para>
the normal rules of SQL Boolean expressions. Two rows are considered
equal if all their corresponding members are non-null and equal; the rows
are unequal if any corresponding members are non-null and unequal;
- otherwise the result of that row comparison is unknown (NULL).
- If there is at least one NULL row result, then the result of <token>ALL</token>
- cannot be TRUE; it will be FALSE or NULL.
+ otherwise the result of that row comparison is unknown (null).
+ If there is at least one null row result, then the result of <token>ALL</token>
+ cannot be true; it will be false or null.
</para>
+ </sect2>
- <bridgehead renderas="sect2">Row-wise comparison</bridgehead>
+ <sect2>
+ <title>Row-wise Comparison</title>
<synopsis>
-(<replaceable>expression</replaceable>, <replaceable>expression</replaceable><optional>, ...</optional>) <replaceable>operator</replaceable> (<replaceable>subquery</replaceable>)
-(<replaceable>expression</replaceable>, <replaceable>expression</replaceable><optional>, ...</optional>) <replaceable>operator</replaceable> (<replaceable>expression</replaceable> <replaceable>expression</replaceable><optional>, ...</optional>)
+(<replaceable>expression</replaceable> <optional>, <replaceable>expression</replaceable> ...</optional>) <replaceable>operator</replaceable> (<replaceable>subquery</replaceable>)
+(<replaceable>expression</replaceable> <optional>, <replaceable>expression</replaceable> ...</optional>) <replaceable>operator</replaceable> (<replaceable>expression</replaceable> <optional>, <replaceable>expression</replaceable> ...</optional>)
</synopsis>
<para>
parenthesized subquery, which must return exactly as many columns as there
are expressions on the left-hand side. Furthermore, the subquery cannot
return more than one row. (If it returns zero rows, the result is taken to
- be NULL.) The left-hand side is evaluated and compared row-wise to the
+ be null.) The left-hand side is evaluated and compared row-wise to the
single subquery result row, or to the right-hand expression list.
Presently, only <literal>=</literal> and <literal><></literal> operators are allowed
in row-wise comparisons.
- The result is TRUE if the two rows are equal or unequal, respectively.
+ The result is <quote>true</> if the two rows are equal or unequal, respectively.
</para>
<para>
the normal rules of SQL Boolean expressions. Two rows are considered
equal if all their corresponding members are non-null and equal; the rows
are unequal if any corresponding members are non-null and unequal;
- otherwise the result of the row comparison is unknown (NULL).
+ otherwise the result of the row comparison is unknown (null).
</para>
-
+ </sect2>
</sect1>
</chapter>
-<!-- $Header: /cvsroot/pgsql/doc/src/sgml/indices.sgml,v 1.37 2002/09/21 18:32:53 petere Exp $ -->
+<!-- $Header: /cvsroot/pgsql/doc/src/sgml/indices.sgml,v 1.37.2.1 2002/11/10 12:45:42 petere Exp $ -->
<chapter id="indexes">
<title id="indexes-title">Indexes</title>
</sect1>
- <sect1 id="keys">
- <title id="keys-title">Keys</title>
-
- <para>
- <note>
- <title>Author</title>
- <para>
- Written by Herouth Maoz (<email>herouth@oumail.openu.ac.il</email>).
- This originally appeared on the User's Mailing List on 1998-03-02
- in response to the question:
- "What is the difference between PRIMARY KEY and UNIQUE constraints?".
- </para>
- </note>
- </para>
-
- <para>
-<literallayout>
-Subject: Re: [QUESTIONS] PRIMARY KEY | UNIQUE
-
- What's the difference between:
-
- PRIMARY KEY(fields,...) and
- UNIQUE (fields,...)
-
- - Is this an alias?
- - If PRIMARY KEY is already unique, then why
- is there another kind of key named UNIQUE?
-</literallayout>
- </para>
-
- <para>
- A primary key is the field(s) used to identify a specific row. For example,
- Social Security numbers identifying a person.
- </para>
-
- <para>
- A simply UNIQUE combination of fields has nothing to do with identifying
- the row. It's simply an integrity constraint. For example, I have
- collections of links. Each collection is identified by a unique number,
- which is the primary key. This key is used in relations.
- </para>
-
- <para>
- However, my application requires that each collection will also have a
- unique name. Why? So that a human being who wants to modify a collection
- will be able to identify it. It's much harder to know, if you have two
- collections named <quote>Life Science</quote>, the one tagged 24433 is the one you
- need, and the one tagged 29882 is not.
- </para>
-
- <para>
- So, the user selects the collection by its name. We therefore make sure,
- within the database, that names are unique. However, no other table in the
- database relates to the collections table by the collection Name. That
- would be very inefficient.
- </para>
-
- <para>
- Moreover, despite being unique, the collection name does not actually
- define the collection! For example, if somebody decided to change the name
- of the collection from <quote>Life Science</quote> to <quote>Biology</quote>, it will still be the
- same collection, only with a different name. As long as the name is unique,
- that's OK.
- </para>
-
- <para>
- So:
-
- <itemizedlist>
- <listitem>
- <para>
- Primary key:
- <itemizedlist spacing="compact" mark="bullet">
- <listitem>
- <para>
- Is used for identifying the row and relating to it.
- </para>
- </listitem>
- <listitem>
- <para>
- Is impossible (or hard) to update.
- </para>
- </listitem>
- <listitem>
- <para>
- Should not allow null values.
- </para>
- </listitem>
- </itemizedlist>
- </para>
- </listitem>
-
- <listitem>
- <para>
- Unique field(s):
- <itemizedlist spacing="compact" mark="bullet">
- <listitem>
- <para>
- Are used as an alternative access to the row.
- </para>
- </listitem>
- <listitem>
- <para>
- Are updatable, so long as they are kept unique.
- </para>
- </listitem>
- <listitem>
- <para>
- Null values are acceptable.
- </para>
- </listitem>
- </itemizedlist>
- </para>
- </listitem>
- </itemizedlist>
- </para>
-
- <para>
- As for why no non-unique keys are defined explicitly in standard
- <acronym>SQL</acronym> syntax? Well, you
- must understand that indexes are implementation-dependent.
- <acronym>SQL</acronym> does not
- define the implementation, merely the relations between data in the
- database. <productname>PostgreSQL</productname> does allow
- non-unique indexes, but indexes
- used to enforce <acronym>SQL</acronym> keys are always unique.
- </para>
-
- <para>
- Thus, you may query a table by any combination of its columns, despite the
- fact that you don't have an index on these columns. The indexes are merely
- an implementation aid that each <acronym>RDBMS</acronym> offers
- you, in order to cause
- commonly used queries to be done more efficiently.
- Some <acronym>RDBMS</acronym> may give you
- additional measures, such as keeping a key stored in main memory. They will
- have a special command, for example
-<synopsis>
-CREATE MEMSTORE ON <replaceable>table</replaceable> COLUMNS <replaceable>cols</replaceable>
-</synopsis>
- (This is not an existing command, just an example.)
- </para>
-
- <para>
- In fact, when you create a primary key or a unique combination of fields,
- nowhere in the <acronym>SQL</acronym> specification does it say
- that an index is created, nor that
- the retrieval of data by the key is going to be more efficient than a
- sequential scan!
- </para>
-
- <para>
- So, if you want to use a combination of fields that is not unique as a
- secondary key, you really don't have to specify anything - just start
- retrieving by that combination! However, if you want to make the retrieval
- efficient, you'll have to resort to the means your
- <acronym>RDBMS</acronym> provider gives you
- - be it an index, my imaginary <literal>MEMSTORE</literal> command, or an intelligent
- <acronym>RDBMS</acronym>
- that creates indexes without your knowledge based on the fact that you have
- sent it many queries based on a specific combination of keys... (It learns
- from experience).
- </para>
- </sect1>
-
-
<sect1 id="indexes-partial">
<title>Partial Indexes</title>
<para>
When indexes are not used, it can be useful for testing to force
their use. There are run-time parameters that can turn off
- various plan types (described in the <citetitle>Administrator's
- Guide</citetitle>). For instance, turning off sequential scans
+ various plan types (described in the &cite-admin;).
+ For instance, turning off sequential scans
(<varname>enable_seqscan</>) and nested-loop joins
(<varname>enable_nestloop</>), which are the most basic plans,
will force the system to use a different plan. If the system
again, two possibilities. The total cost is computed from the
per-row costs of each plan node times the selectivity estimate of
the plan node. The costs of the plan nodes can be tuned with
- run-time parameters (described in the <citetitle>Administrator's
- Guide</citetitle>). An inaccurate selectivity estimate is due to
+ run-time parameters (described in the &cite-admin;).
+ An inaccurate selectivity estimate is due to
insufficient statistics. It may be possible to help this by
tuning the statistics-gathering parameters (see <command>ALTER
TABLE</command> reference).
-<!-- $Header: /cvsroot/pgsql/doc/src/sgml/keywords.sgml,v 2.7 2002/11/02 18:41:21 tgl Exp $ -->
+<!-- $Header: /cvsroot/pgsql/doc/src/sgml/keywords.sgml,v 2.7.2.1 2002/11/10 12:45:42 petere Exp $ -->
<appendix id="sql-keywords-appendix">
<title><acronym>SQL</acronym> Key Words</title>
</row>
<row>
<entry><token>ASSERTION</token></entry>
- <entry></entry>
+ <entry>non-reserved</entry>
<entry>reserved</entry>
<entry>reserved</entry>
</row>
<row>
<entry><token>ASSIGNMENT</token></entry>
- <entry></entry>
+ <entry>non-reserved</entry>
<entry>non-reserved</entry>
<entry></entry>
</row>
</row>
<row>
<entry><token>AUTHORIZATION</token></entry>
- <entry>non-reserved</entry>
+ <entry>reserved (can be function)</entry>
<entry>reserved</entry>
<entry>reserved</entry>
</row>
<entry>non-reserved</entry>
<entry>reserved</entry>
</row>
+ <row>
+ <entry><token>BIGINT</token></entry>
+ <entry>non-reserved (cannot be function or type)</entry>
+ <entry></entry>
+ <entry></entry>
+ </row>
<row>
<entry><token>BINARY</token></entry>
<entry>reserved (can be function)</entry>
</row>
<row>
<entry><token>BOOLEAN</token></entry>
- <entry></entry>
+ <entry>non-reserved (cannot be function or type)</entry>
<entry>reserved</entry>
<entry></entry>
</row>
</row>
<row>
<entry><token>CALLED</token></entry>
- <entry></entry>
+ <entry>non-reserved</entry>
<entry>non-reserved</entry>
<entry></entry>
</row>
</row>
<row>
<entry><token>CLASS</token></entry>
- <entry></entry>
+ <entry>non-reserved</entry>
<entry>reserved</entry>
<entry></entry>
</row>
<entry>reserved</entry>
<entry>reserved</entry>
</row>
+ <row>
+ <entry><token>CONVERSION</token></entry>
+ <entry>non-reserved</entry>
+ <entry></entry>
+ <entry></entry>
+ </row>
<row>
<entry><token>CONVERT</token></entry>
<entry>non-reserved (cannot be function or type)</entry>
</row>
<row>
<entry><token>CREATE</token></entry>
- <entry>non-reserved</entry>
+ <entry>reserved</entry>
<entry>reserved</entry>
<entry>reserved</entry>
</row>
</row>
<row>
<entry><token>DEALLOCATE</token></entry>
- <entry></entry>
+ <entry>non-reserved</entry>
<entry>reserved</entry>
<entry>reserved</entry>
</row>
</row>
<row>
<entry><token>DEFINER</token></entry>
- <entry></entry>
+ <entry>non-reserved</entry>
<entry>non-reserved</entry>
<entry></entry>
</row>
</row>
<row>
<entry><token>DOMAIN</token></entry>
- <entry></entry>
+ <entry>non-reserved</entry>
<entry>reserved</entry>
<entry>reserved</entry>
</row>
</row>
<row>
<entry><token>EXTERNAL</token></entry>
- <entry></entry>
+ <entry>non-reserved</entry>
<entry>reserved</entry>
<entry>reserved</entry>
</row>
</row>
<row>
<entry><token>GET</token></entry>
- <entry></entry>
+ <entry>non-reserved</entry>
<entry>reserved</entry>
<entry>reserved</entry>
</row>
</row>
<row>
<entry><token>GRANT</token></entry>
- <entry>non-reserved</entry>
+ <entry>reserved</entry>
<entry>reserved</entry>
<entry>reserved</entry>
</row>
<entry>reserved</entry>
<entry>reserved</entry>
</row>
+ <row>
+ <entry><token>IMMUTABLE</token></entry>
+ <entry>non-reserved</entry>
+ <entry></entry>
+ <entry></entry>
+ </row>
<row>
<entry><token>IMPLEMENTATION</token></entry>
<entry></entry>
<entry>non-reserved</entry>
<entry></entry>
</row>
+ <row>
+ <entry><token>IMPLICIT</token></entry>
+ <entry>non-reserved</entry>
+ <entry></entry>
+ <entry></entry>
+ </row>
<row>
<entry><token>IN</token></entry>
<entry>reserved (can be function)</entry>
</row>
<row>
<entry><token>INPUT</token></entry>
- <entry></entry>
+ <entry>non-reserved</entry>
<entry>reserved</entry>
<entry>reserved</entry>
</row>
</row>
<row>
<entry><token>INT</token></entry>
- <entry></entry>
+ <entry>non-reserved (cannot be function or type)</entry>
<entry>reserved</entry>
<entry>reserved</entry>
</row>
<row>
<entry><token>INTEGER</token></entry>
- <entry></entry>
+ <entry>non-reserved (cannot be function or type)</entry>
<entry>reserved</entry>
<entry>reserved</entry>
</row>
</row>
<row>
<entry><token>INVOKER</token></entry>
- <entry></entry>
+ <entry>non-reserved</entry>
<entry>non-reserved</entry>
<entry></entry>
</row>
</row>
<row>
<entry><token>LOCALTIME</token></entry>
- <entry></entry>
+ <entry>reserved</entry>
<entry>reserved</entry>
<entry></entry>
</row>
<row>
<entry><token>LOCALTIMESTAMP</token></entry>
- <entry></entry>
+ <entry>reserved</entry>
<entry>reserved</entry>
<entry></entry>
</row>
</row>
<row>
<entry><token>OVERLAY</token></entry>
- <entry></entry>
+ <entry>non-reserved (cannot be function or type)</entry>
<entry>non-reserved</entry>
<entry></entry>
</row>
<entry></entry>
<entry></entry>
</row>
+ <row>
+ <entry><token>PLACING</token></entry>
+ <entry>reserved</entry>
+ <entry></entry>
+ <entry></entry>
+ </row>
<row>
<entry><token>PLI</token></entry>
<entry></entry>
</row>
<row>
<entry><token>PREPARE</token></entry>
- <entry></entry>
+ <entry>non-reserved</entry>
<entry>reserved</entry>
<entry>reserved</entry>
</row>
</row>
<row>
<entry><token>PUBLIC</token></entry>
- <entry>reserved (can be function)</entry>
+ <entry></entry>
<entry>reserved</entry>
<entry>reserved</entry>
</row>
</row>
<row>
<entry><token>REAL</token></entry>
- <entry></entry>
+ <entry>non-reserved (cannot be function or type)</entry>
<entry>reserved</entry>
<entry>reserved</entry>
</row>
+ <row>
+ <entry><token>RECHECK</token></entry>
+ <entry>non-reserved</entry>
+ <entry></entry>
+ <entry></entry>
+ </row>
<row>
<entry><token>RECURSIVE</token></entry>
<entry></entry>
</row>
<row>
<entry><token>ROW</token></entry>
- <entry>non-reserved</entry>
+ <entry>non-reserved (cannot be function or type)</entry>
<entry>reserved</entry>
<entry></entry>
</row>
</row>
<row>
<entry><token>SECURITY</token></entry>
- <entry></entry>
+ <entry>non-reserved</entry>
<entry>non-reserved</entry>
<entry></entry>
</row>
</row>
<row>
<entry><token>SIMILAR</token></entry>
- <entry></entry>
+ <entry>reserved (can be function)</entry>
<entry>non-reserved</entry>
<entry></entry>
</row>
<row>
<entry><token>SIMPLE</token></entry>
- <entry></entry>
+ <entry>non-reserved</entry>
<entry>non-reserved</entry>
<entry></entry>
</row>
</row>
<row>
<entry><token>SMALLINT</token></entry>
- <entry></entry>
+ <entry>non-reserved (cannot be function or type)</entry>
<entry>reserved</entry>
<entry>reserved</entry>
</row>
<entry>reserved</entry>
<entry></entry>
</row>
+ <row>
+ <entry><token>STABLE</token></entry>
+ <entry>non-reserved</entry>
+ <entry></entry>
+ <entry></entry>
+ </row>
<row>
<entry><token>START</token></entry>
<entry>non-reserved</entry>
<entry></entry>
<entry></entry>
</row>
+ <row>
+ <entry><token>STORAGE</token></entry>
+ <entry>non-reserved</entry>
+ <entry></entry>
+ <entry></entry>
+ </row>
+ <row>
+ <entry><token>STRICT</token></entry>
+ <entry>non-reserved</entry>
+ <entry></entry>
+ <entry></entry>
+ </row>
<row>
<entry><token>STRUCTURE</token></entry>
<entry></entry>
</row>
<row>
<entry><token>TREAT</token></entry>
- <entry></entry>
+ <entry>non-reserved (cannot be function or type)</entry>
<entry>reserved</entry>
<entry></entry>
</row>
</row>
<row>
<entry><token>USAGE</token></entry>
- <entry></entry>
+ <entry>non-reserved</entry>
<entry>reserved</entry>
<entry>reserved</entry>
</row>
<entry></entry>
<entry></entry>
</row>
+ <row>
+ <entry><token>VALIDATOR</token></entry>
+ <entry>non-reserved</entry>
+ <entry></entry>
+ <entry></entry>
+ </row>
<row>
<entry><token>VALUE</token></entry>
<entry></entry>
<entry>reserved</entry>
<entry>reserved</entry>
</row>
+ <row>
+ <entry><token>VOLATILE</token></entry>
+ <entry>non-reserved</entry>
+ <entry></entry>
+ <entry></entry>
+ </row>
<row>
<entry><token>WHEN</token></entry>
<entry>reserved</entry>
</row>
<row>
<entry><token>WRITE</token></entry>
- <entry></entry>
+ <entry>non-reserved</entry>
<entry>reserved</entry>
<entry>reserved</entry>
</row>
<!--
-$Header: /cvsroot/pgsql/doc/src/sgml/mvcc.sgml,v 2.28 2002/09/21 18:32:53 petere Exp $
+$Header: /cvsroot/pgsql/doc/src/sgml/mvcc.sgml,v 2.28.2.1 2002/11/10 12:45:42 petere Exp $
-->
<chapter id="mvcc">
<primary>concurrency</primary>
</indexterm>
- <abstract>
- <para>
- Multiversion Concurrency Control
- (MVCC)
- is an advanced technique for improving database performance in a
- multiuser environment.
- Vadim Mikheev (<email>vadim@krs.ru</email>) provided
- the implementation for <productname>PostgreSQL</productname>.
- </para>
- </abstract>
+ <para>
+ This chapter describes the behavior of the PostgreSQL database
+ system when two or more sessions try to access the same data at the
+ same time. The goals in that situation are to allow efficient
+ access for all sessions while maintaining strict data integrity.
+ Every developer of database applications should be familiar with
+ the topics covered in this chapter.
+ </para>
<sect1 id="mvcc-intro">
<title>Introduction</title>
<para>
- Unlike most other database systems which use locks for concurrency control,
+ Unlike traditional database systems which use locks for concurrency control,
<productname>PostgreSQL</productname>
- maintains data consistency by using a multiversion model.
+ maintains data consistency by using a multiversion model
+ (Multiversion Concurrency Control, <acronym>MVCC</acronym>).
This means that while querying a database each transaction sees
a snapshot of data (a <firstterm>database version</firstterm>)
as it was some
<title>Transaction Isolation</title>
<para>
- The <acronym>ANSI</acronym>/<acronym>ISO</acronym> <acronym>SQL</acronym>
+ The <acronym>SQL</acronym>
standard defines four levels of transaction
isolation in terms of three phenomena that must be prevented
between concurrent transactions.
<variablelist>
<varlistentry>
<term>
- dirty reads
- <indexterm><primary>dirty reads</primary></indexterm>
+ dirty read
+ <indexterm><primary>dirty read</primary></indexterm>
</term>
<listitem>
<para>
<varlistentry>
<term>
- non-repeatable reads
- <indexterm><primary>non-repeatable reads</primary></indexterm>
+ nonrepeatable read
+ <indexterm><primary>nonrepeatable read</primary></indexterm>
</term>
<listitem>
<para>
<varlistentry>
<term>
phantom read
- <indexterm><primary>phantom reads</primary></indexterm>
+ <indexterm><primary>phantom read</primary></indexterm>
</term>
<listitem>
<para>
</indexterm>
The four transaction isolation levels and the corresponding
behaviors are described in <xref linkend="mvcc-isolevel-table">.
+ </para>
<table tocentry="1" id="mvcc-isolevel-table">
<title><acronym>SQL</acronym> Transaction Isolation Levels</title>
Dirty Read
</entry>
<entry>
- Non-Repeatable Read
+ Nonrepeatable Read
</entry>
<entry>
Phantom Read
</tbody>
</tgroup>
</table>
- </para>
<para>
<productname>PostgreSQL</productname>
offers the read committed and serializable isolation levels.
</para>
- </sect1>
- <sect1 id="xact-read-committed">
+ <sect2 id="xact-read-committed">
<title>Read Committed Isolation Level</title>
<indexterm>
</para>
<para>
- <command>UPDATE</command>, <command>DELETE</command> and <command>SELECT
+ <command>UPDATE</command>, <command>DELETE</command>, and <command>SELECT
FOR UPDATE</command> commands behave the same as <command>SELECT</command>
in terms of searching for target rows: they will only find target rows
that were committed as of the query start time. However, such a target
be necessary to guarantee a more rigorously consistent view of the
database than the Read Committed mode provides.
</para>
- </sect1>
+ </sect2>
- <sect1 id="xact-serializable">
+ <sect2 id="xact-serializable">
<title>Serializable Isolation Level</title>
<indexterm>
committed.) This is different from Read Committed in that the
<command>SELECT</command>
sees a snapshot as of the start of the transaction, not as of the start
- of the current query within the transaction. Successive
+ of the current query within the transaction. Thus, successive
<command>SELECT</command>s within a single transaction always see the same
data.
</para>
<para>
- <command>UPDATE</command>, <command>DELETE</command> and <command>SELECT
+ <command>UPDATE</command>, <command>DELETE</command>, and <command>SELECT
FOR UPDATE</command> commands behave the same as <command>SELECT</command>
in terms of searching for target rows: they will only find target rows
that were committed as of the transaction start time. However, such a
a transaction performs several successive queries that must see
identical views of the database.
</para>
- </sect1>
+ </sect2>
+ </sect1>
<sect1 id="explicit-locking">
<title>Explicit Locking</title>
To examine a list of the currently outstanding locks in a
database server, use the <literal>pg_locks</literal> system
view. For more information on monitoring the status of the lock
- manager subsystem, refer to the <citetitle>Administrator's
- Guide</citetitle>.
+ manager subsystem, refer to the &cite-admin;.
</para>
<variablelist>
<para>
Use of explicit locking can cause <firstterm>deadlocks</>, wherein
two (or more) transactions each hold locks that the other wants.
- For example, if transaction 1 acquires exclusive lock on table A
- and then tries to acquire exclusive lock on table B, while transaction
- 2 has already exclusive-locked table B and now wants exclusive lock
+ For example, if transaction 1 acquires an exclusive lock on table A
+ and then tries to acquire an exclusive lock on table B, while transaction
+ 2 has already exclusive-locked table B and now wants an exclusive lock
on table A, then neither one can proceed.
<productname>PostgreSQL</productname> automatically detects deadlock
situations and resolves them by aborting one of the transactions
involved, allowing the other(s) to complete. (Exactly which transaction
- will be aborted is difficult to predict, and should not be relied on.)
+ will be aborted is difficult to predict and should not be relied on.)
</para>
<para>
</sect1>
<sect1 id="applevel-consistency">
- <title>Data consistency checks at the application level</title>
+ <title>Data Consistency Checks at the Application Level</title>
<para>
Because readers in <productname>PostgreSQL</productname>
<note>
<para>
- Before version 6.5 <productname>PostgreSQL</productname>
- used read-locks and so the
- above consideration is also the case
- when upgrading to 6.5 (or higher) from previous
- <productname>PostgreSQL</productname> versions.
+ Before version 6.5 <productname>PostgreSQL</productname> used
+ read locks, and so the above consideration is also the case when
+ upgrading from <productname>PostgreSQL</productname> versions
+ prior to 6.5.
</para>
</note>
</para>
example, a banking application might wish to check that the sum of
all credits in one table equals the sum of debits in another table,
when both tables are being actively updated. Comparing the results of two
- successive SELECT SUM(...) commands will not work reliably under
+ successive <literal>SELECT SUM(...)</literal> commands will not work reliably under
Read Committed mode, since the second query will likely include the results
of transactions not counted by the first. Doing the two sums in a
single serializable transaction will give an accurate picture of the
the table are still running --- but if the snapshot seen by the
transaction predates obtaining the lock, it may predate some now-committed
changes in the table. A serializable transaction's snapshot is actually
- frozen at the start of its first query (SELECT/INSERT/UPDATE/DELETE), so
+ frozen at the start of its first query (<literal>SELECT</>, <literal>INSERT</>,
+ <literal>UPDATE</>, or <literal>DELETE</>), so
it's possible to obtain explicit locks before the snapshot is
frozen.
</para>
<variablelist>
<varlistentry>
<term>
- <acronym>GiST</acronym> and R-Tree indexes
+ B-tree indexes
</term>
<listitem>
<para>
- Share/exclusive index-level locks are used for read/write access.
- Locks are released after statement is done.
+ Short-term share/exclusive page-level locks are used for
+ read/write access. Locks are released immediately after each
+ index tuple is fetched or inserted. B-tree indexes provide
+ the highest concurrency without deadlock conditions.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>
- Hash indexes
+ <acronym>GiST</acronym> and R-tree indexes
</term>
<listitem>
<para>
- Share/exclusive page-level locks are used for read/write access.
- Locks are released after page is processed.
- </para>
-
- <para>
- Page-level locks provide better concurrency than index-level ones
- but are subject to deadlocks.
+ Share/exclusive index-level locks are used for read/write access.
+ Locks are released after the statement (command) is done.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>
- B-tree indexes
+ Hash indexes
</term>
<listitem>
<para>
- Short-term share/exclusive page-level locks are used for
- read/write access. Locks are released immediately after each index
- tuple is fetched/inserted.
- </para>
-
- <para>
- B-tree indexes provide the highest concurrency without deadlock
- conditions.
+ Share/exclusive page-level locks are used for read/write
+ access. Locks are released after the page is processed.
+ Page-level locks provide better concurrency than index-level
+ ones but are liable to deadlocks.
</para>
</listitem>
</varlistentry>
<!--
-$Header: /cvsroot/pgsql/doc/src/sgml/perform.sgml,v 1.21 2002/09/21 18:32:53 petere Exp $
+$Header: /cvsroot/pgsql/doc/src/sgml/perform.sgml,v 1.21.2.1 2002/11/10 12:45:42 petere Exp $
-->
<chapter id="performance-tips">
<itemizedlist>
<listitem>
<para>
- Estimated start-up cost (time expended before output scan can start,
- e.g., time to do the sorting in a SORT node).
+ Estimated start-up cost (Time expended before output scan can start,
+ e.g., time to do the sorting in a sort node.)
</para>
</listitem>
<listitem>
<para>
- Estimated total cost (if all tuples are retrieved, which they may not
- be --- a query with a LIMIT will stop short of paying the total cost,
- for example).
+ Estimated total cost (If all rows are retrieved, which they may not
+ be --- a query with a <literal>LIMIT</> clause will stop short of paying the total cost,
+ for example.)
</para>
</listitem>
<listitem>
<para>
- Estimated number of rows output by this plan node (again, only if
- executed to completion).
+ Estimated number of rows output by this plan node (Again, only if
+ executed to completion.)
</para>
</listitem>
<listitem>
<para>
Estimated average width (in bytes) of rows output by this plan
- node.
+ node
</para>
</listitem>
</itemizedlist>
<para>
The costs are measured in units of disk page fetches. (CPU effort
estimates are converted into disk-page units using some
- fairly arbitrary fudge-factors. If you want to experiment with these
+ fairly arbitrary fudge factors. If you want to experiment with these
factors, see the list of run-time configuration parameters in the
- <citetitle>Administrator's Guide</citetitle>.)
+ &cite-admin;.)
</para>
<para>
the cost of all its child nodes. It's also important to realize that
the cost only reflects things that the planner/optimizer cares about.
In particular, the cost does not consider the time spent transmitting
- result tuples to the frontend --- which could be a pretty dominant
+ result rows to the frontend --- which could be a pretty dominant
factor in the true elapsed time, but the planner ignores it because
it cannot change it by altering the plan. (Every correct plan will
- output the same tuple set, we trust.)
+ output the same row set, we trust.)
</para>
<para>
Rows output is a little tricky because it is <emphasis>not</emphasis> the
number of rows
processed/scanned by the query --- it is usually less, reflecting the
- estimated selectivity of any WHERE-clause constraints that are being
+ estimated selectivity of any <literal>WHERE</>-clause constraints that are being
applied at this node. Ideally the top-level rows estimate will
approximate the number of rows actually returned, updated, or deleted
by the query.
<para>
Here are some examples (using the regress test database after a
- vacuum analyze, and 7.3 development sources):
+ <literal>VACUUM ANALYZE</>, and 7.3 development sources):
- <programlisting>
+<programlisting>
regression=# EXPLAIN SELECT * FROM tenk1;
QUERY PLAN
-------------------------------------------------------------
Seq Scan on tenk1 (cost=0.00..333.00 rows=10000 width=148)
- </programlisting>
+</programlisting>
</para>
<para>
This is about as straightforward as it gets. If you do
- <programlisting>
+<programlisting>
SELECT * FROM pg_class WHERE relname = 'tenk1';
- </programlisting>
+</programlisting>
you will find out that <classname>tenk1</classname> has 233 disk
- pages and 10000 tuples. So the cost is estimated at 233 page
- reads, defined as 1.0 apiece, plus 10000 * <varname>cpu_tuple_cost</varname> which is
- currently 0.01 (try <command>show cpu_tuple_cost</command>).
+ pages and 10000 rows. So the cost is estimated at 233 page
+ reads, defined as costing 1.0 apiece, plus 10000 * <varname>cpu_tuple_cost</varname> which is
+ currently 0.01 (try <command>SHOW cpu_tuple_cost</command>).
</para>
<para>
- Now let's modify the query to add a WHERE condition:
+ Now let's modify the query to add a <literal>WHERE</> condition:
- <programlisting>
+<programlisting>
regression=# EXPLAIN SELECT * FROM tenk1 WHERE unique1 < 1000;
QUERY PLAN
------------------------------------------------------------
Seq Scan on tenk1 (cost=0.00..358.00 rows=1033 width=148)
Filter: (unique1 < 1000)
- </programlisting>
+</programlisting>
- The estimate of output rows has gone down because of the WHERE clause.
+ The estimate of output rows has gone down because of the <literal>WHERE</> clause.
However, the scan will still have to visit all 10000 rows, so the cost
hasn't decreased; in fact it has gone up a bit to reflect the extra CPU
- time spent checking the WHERE condition.
+ time spent checking the <literal>WHERE</> condition.
</para>
<para>
<para>
Modify the query to restrict the condition even more:
- <programlisting>
+<programlisting>
regression=# EXPLAIN SELECT * FROM tenk1 WHERE unique1 < 50;
QUERY PLAN
-------------------------------------------------------------------------------
Index Scan using tenk1_unique1 on tenk1 (cost=0.00..179.33 rows=49 width=148)
Index Cond: (unique1 < 50)
- </programlisting>
+</programlisting>
- and you will see that if we make the WHERE condition selective
+ and you will see that if we make the <literal>WHERE</> condition selective
enough, the planner will
eventually decide that an index scan is cheaper than a sequential scan.
- This plan will only have to visit 50 tuples because of the index,
+ This plan will only have to visit 50 rows because of the index,
so it wins despite the fact that each individual fetch is more expensive
than reading a whole disk page sequentially.
</para>
<para>
- Add another clause to the WHERE condition:
+ Add another clause to the <literal>WHERE</> condition:
- <programlisting>
+<programlisting>
regression=# EXPLAIN SELECT * FROM tenk1 WHERE unique1 < 50 AND
regression-# stringu1 = 'xxx';
QUERY PLAN
Index Scan using tenk1_unique1 on tenk1 (cost=0.00..179.45 rows=1 width=148)
Index Cond: (unique1 < 50)
Filter: (stringu1 = 'xxx'::name)
- </programlisting>
+</programlisting>
The added clause <literal>stringu1 = 'xxx'</literal> reduces the
output-rows estimate, but not the cost because we still have to visit the
- same set of tuples. Notice that the <literal>stringu1</> clause
+ same set of rows. Notice that the <literal>stringu1</> clause
cannot be applied as an index condition (since this index is only on
the <literal>unique1</> column). Instead it is applied as a filter on
the rows retrieved by the index. Thus the cost has actually gone up
<para>
Let's try joining two tables, using the fields we have been discussing:
- <programlisting>
+<programlisting>
regression=# EXPLAIN SELECT * FROM tenk1 t1, tenk2 t2 WHERE t1.unique1 < 50
regression-# AND t1.unique2 = t2.unique2;
QUERY PLAN
-> Index Scan using tenk2_unique2 on tenk2 t2
(cost=0.00..3.01 rows=1 width=148)
Index Cond: ("outer".unique2 = t2.unique2)
- </programlisting>
+</programlisting>
</para>
<para>
In this nested-loop join, the outer scan is the same index scan we had
in the example before last, and so its cost and row count are the same
- because we are applying the <literal>unique1 < 50</literal> WHERE clause at that node.
+ because we are applying the <literal>unique1 < 50</literal> <literal>WHERE</> clause at that node.
The <literal>t1.unique2 = t2.unique2</literal> clause is not relevant yet, so it doesn't
- affect row count of the outer scan. For the inner scan, the unique2 value of the
+ affect row count of the outer scan. For the inner scan, the <literal>unique2</> value of the
current
- outer-scan tuple is plugged into the inner index scan
+ outer-scan row is plugged into the inner index scan
to produce an index condition like
<literal>t2.unique2 = <replaceable>constant</replaceable></literal>. So we get the
- same inner-scan plan and costs that we'd get from, say, <literal>explain select
- * from tenk2 where unique2 = 42</literal>. The costs of the loop node are then set
+ same inner-scan plan and costs that we'd get from, say, <literal>EXPLAIN SELECT
+ * FROM tenk2 WHERE unique2 = 42</literal>. The costs of the loop node are then set
on the basis of the cost of the outer scan, plus one repetition of the
- inner scan for each outer tuple (49 * 3.01, here), plus a little CPU
+ inner scan for each outer row (49 * 3.01, here), plus a little CPU
time for join processing.
</para>
<para>
In this example the loop's output row count is the same as the product
of the two scans' row counts, but that's not true in general, because
- in general you can have WHERE clauses that mention both relations and
+ in general you can have <literal>WHERE</> clauses that mention both relations and
so can only be applied at the join point, not to either input scan.
For example, if we added <literal>WHERE ... AND t1.hundred < t2.hundred</literal>,
that would decrease the output row count of the join node, but not change
flags for each plan type. (This is a crude tool, but useful. See
also <xref linkend="explicit-joins">.)
- <programlisting>
-regression=# set enable_nestloop = off;
-SET VARIABLE
+<programlisting>
+regression=# SET enable_nestloop = off;
+SET
regression=# EXPLAIN SELECT * FROM tenk1 t1, tenk2 t2 WHERE t1.unique1 < 50
regression-# AND t1.unique2 = t2.unique2;
QUERY PLAN
-> Index Scan using tenk1_unique1 on tenk1 t1
(cost=0.00..179.33 rows=49 width=148)
Index Cond: (unique1 < 50)
- </programlisting>
+</programlisting>
This plan proposes to extract the 50 interesting rows of <classname>tenk1</classname>
using ye same olde index scan, stash them into an in-memory hash table,
and then do a sequential scan of <classname>tenk2</classname>, probing into the hash table
- for possible matches of <literal>t1.unique2 = t2.unique2</literal> at each <classname>tenk2</classname> tuple.
+ for possible matches of <literal>t1.unique2 = t2.unique2</literal> at each <classname>tenk2</classname> row.
The cost to read <classname>tenk1</classname> and set up the hash table is entirely start-up
- cost for the hash join, since we won't get any tuples out until we can
+ cost for the hash join, since we won't get any rows out until we can
start reading <classname>tenk2</classname>. The total time estimate for the join also
- includes a hefty charge for CPU time to probe the hash table
- 10000 times. Note, however, that we are NOT charging 10000 times 179.33;
+ includes a hefty charge for the CPU time to probe the hash table
+ 10000 times. Note, however, that we are <emphasis>not</emphasis> charging 10000 times 179.33;
the hash table setup is only done once in this plan type.
</para>
<para>
It is possible to check on the accuracy of the planner's estimated costs
- by using EXPLAIN ANALYZE. This command actually executes the query,
+ by using <command>EXPLAIN ANALYZE</>. This command actually executes the query,
and then displays the true run time accumulated within each plan node
- along with the same estimated costs that a plain EXPLAIN shows.
+ along with the same estimated costs that a plain <command>EXPLAIN</command> shows.
For example, we might get a result like this:
<screen>
<para>
In some query plans, it is possible for a subplan node to be executed more
than once. For example, the inner index scan is executed once per outer
- tuple in the above nested-loop plan. In such cases, the
+ row in the above nested-loop plan. In such cases, the
<quote>loops</quote> value reports the
total number of executions of the node, and the actual time and rows
values shown are averages per-execution. This is done to make the numbers
<para>
The <literal>Total runtime</literal> shown by <command>EXPLAIN ANALYZE</command> includes
- executor start-up and shutdown time, as well as time spent processing
- the result tuples. It does not include parsing, rewriting, or planning
- time. For a SELECT query, the total run time will normally be just a
+ executor start-up and shut-down time, as well as time spent processing
+ the result rows. It does not include parsing, rewriting, or planning
+ time. For a <command>SELECT</> query, the total run time will normally be just a
little larger than the total time reported for the top-level plan node.
- For INSERT, UPDATE, and DELETE queries, the total run time may be
+ For <command>INSERT</>, <command>UPDATE</>, and <command>DELETE</> commands, the total run time may be
considerably larger, because it includes the time spent processing the
- result tuples. In these queries, the time for the top plan node
- essentially is the time spent computing the new tuples and/or locating
+ result rows. In these commands, the time for the top plan node
+ essentially is the time spent computing the new rows and/or locating
the old ones, but it doesn't include the time spent making the changes.
</para>
<para>
- It is worth noting that EXPLAIN results should not be extrapolated
+ It is worth noting that <command>EXPLAIN</> results should not be extrapolated
to situations other than the one you are actually testing; for example,
results on a toy-sized table can't be assumed to apply to large tables.
The planner's cost estimates are not linear and so it may well choose
</sect1>
<sect1 id="planner-stats">
- <title>Statistics used by the Planner</title>
+ <title>Statistics Used by the Planner</title>
<para>
As we saw in the previous section, the query planner needs to estimate
with queries similar to this one:
<screen>
-regression=# select relname, relkind, reltuples, relpages from pg_class
-regression-# where relname like 'tenk1%';
+regression=# SELECT relname, relkind, reltuples, relpages FROM pg_class
+regression-# WHERE relname LIKE 'tenk1%';
relname | relkind | reltuples | relpages
---------------+---------+-----------+----------
tenk1 | r | 10000 | 233
<para>
Most queries retrieve only a fraction of the rows in a table, due
- to having WHERE clauses that restrict the rows to be examined.
+ to having <literal>WHERE</> clauses that restrict the rows to be examined.
The planner thus needs to make an estimate of the
- <firstterm>selectivity</> of WHERE clauses, that is, the fraction of
- rows that match each clause of the WHERE condition. The information
+ <firstterm>selectivity</> of <literal>WHERE</> clauses, that is, the fraction of
+ rows that match each clause of the <literal>WHERE</> condition. The information
used for this task is stored in the <structname>pg_statistic</structname>
system catalog. Entries in <structname>pg_statistic</structname> are
updated by <command>ANALYZE</> and <command>VACUUM ANALYZE</> commands,
For example, we might do:
<screen>
-regression=# select attname, n_distinct, most_common_vals from pg_stats where tablename = 'road';
+regression=# SELECT attname, n_distinct, most_common_vals FROM pg_stats WHERE tablename = 'road';
attname | n_distinct | most_common_vals
---------+------------+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
name | -0.467008 | {"I- 580 Ramp","I- 880 Ramp","Sp Railroad ","I- 580 ","I- 680 Ramp","I- 80 Ramp","14th St ","5th St ","Mission Blvd","I- 880 "}
(2 rows)
regression=#
</screen>
+ </para>
- As of <productname>PostgreSQL</productname> 7.2 the following columns exist
- in <structname>pg_stats</structname>:
+ <para>
+ <xref linkend="planner-pg-stats-table"> shows the columns that
+ exist in <structname>pg_stats</structname>.
</para>
- <table>
+ <table id="planner-pg-stats-table">
<title><structname>pg_stats</structname> Columns</title>
<tgroup cols=3>
<row>
<entry><literal>tablename</literal></entry>
<entry><type>name</type></entry>
- <entry>Name of table containing column</entry>
+ <entry>Name of the table containing the column</entry>
</row>
<row>
<row>
<entry><literal>null_frac</literal></entry>
<entry><type>real</type></entry>
- <entry>Fraction of column's entries that are NULL</entry>
+ <entry>Fraction of column's entries that are null</entry>
</row>
<row>
<entry><literal>avg_width</literal></entry>
<entry><type>integer</type></entry>
- <entry>Average width in bytes of column's entries</entry>
+ <entry>Average width in bytes of the column's entries</entry>
</row>
<row>
<entry>If greater than zero, the estimated number of distinct values
in the column. If less than zero, the negative of the number of
distinct values divided by the number of rows. (The negated form
- is used when ANALYZE believes that the number of distinct values
+ is used when <command>ANALYZE</> believes that the number of distinct values
is likely to increase as the table grows; the positive form is used
when the column seems to have a fixed number of possible values.)
For example, -1 indicates a unique column in which the number of
<entry><literal>most_common_freqs</literal></entry>
<entry><type>real[]</type></entry>
<entry>A list of the frequencies of the most common values,
- ie, number of occurrences of each divided by total number of rows.
+ i.e., number of occurrences of each divided by total number of rows.
</entry>
</row>
<title>Controlling the Planner with Explicit <literal>JOIN</> Clauses</title>
<para>
- Beginning with <productname>PostgreSQL</productname> 7.1 it is possible
- to control the query planner to some extent by using explicit <literal>JOIN</>
+ Beginning with <productname>PostgreSQL</productname> 7.1 it has been possible
+ to control the query planner to some extent by using the explicit <literal>JOIN</>
syntax. To see why this matters, we first need some background.
</para>
<para>
In a simple join query, such as
- <programlisting>
-SELECT * FROM a,b,c WHERE a.id = b.id AND b.ref = c.id;
- </programlisting>
- the planner is free to join the given tables in any order. For example,
- it could generate a query plan that joins A to B, using the WHERE clause
- a.id = b.id, and then joins C to this joined table, using the other
- WHERE clause. Or it could join B to C and then join A to that result.
- Or it could join A to C and then join them with B --- but that would
- be inefficient, since the full Cartesian product of A and C would have
- to be formed, there being no applicable WHERE clause to allow optimization
- of the join.
- (All joins in the <productname>PostgreSQL</productname> executor happen
- between two input tables, so it's necessary to build up the result in one
- or another of these fashions.) The important point is that these different
- join possibilities give semantically equivalent results but may have hugely
- different execution costs. Therefore, the planner will explore all of them
- to try to find the most efficient query plan.
+<programlisting>
+SELECT * FROM a, b, c WHERE a.id = b.id AND b.ref = c.id;
+</programlisting>
+ the planner is free to join the given tables in any order. For
+ example, it could generate a query plan that joins A to B, using
+ the <literal>WHERE</> condition <literal>a.id = b.id</>, and then
+ joins C to this joined table, using the other <literal>WHERE</>
+ condition. Or it could join B to C and then join A to that result.
+ Or it could join A to C and then join them with B --- but that
+ would be inefficient, since the full Cartesian product of A and C
+ would have to be formed, there being no applicable condition in the
+ <literal>WHERE</> clause to allow optimization of the join. (All
+ joins in the <productname>PostgreSQL</productname> executor happen
+ between two input tables, so it's necessary to build up the result
+ in one or another of these fashions.) The important point is that
+ these different join possibilities give semantically equivalent
+ results but may have hugely different execution costs. Therefore,
+ the planner will explore all of them to try to find the most
+ efficient query plan.
</para>
<para>
search to a <firstterm>genetic</firstterm> probabilistic search
through a limited number of possibilities. (The switch-over threshold is
set by the <varname>GEQO_THRESHOLD</varname> run-time
- parameter described in the <citetitle>Administrator's Guide</citetitle>.)
+ parameter described in the &cite-admin;.)
The genetic search takes less time, but it won't
necessarily find the best possible plan.
</para>
<para>
When the query involves outer joins, the planner has much less freedom
than it does for plain (inner) joins. For example, consider
- <programlisting>
+<programlisting>
SELECT * FROM a LEFT JOIN (b JOIN c ON (b.ref = c.id)) ON (a.id = b.id);
- </programlisting>
+</programlisting>
Although this query's restrictions are superficially similar to the
previous example, the semantics are different because a row must be
emitted for each row of A that has no matching row in the join of B and C.
</para>
<para>
- In <productname>PostgreSQL</productname> 7.1, the planner treats all
- explicit JOIN syntaxes as constraining the join order, even though
+ The <productname>PostgreSQL</productname> query planner treats all
+ explicit <literal>JOIN</> syntaxes as constraining the join order, even though
it is not logically necessary to make such a constraint for inner
joins. Therefore, although all of these queries give the same result:
- <programlisting>
-SELECT * FROM a,b,c WHERE a.id = b.id AND b.ref = c.id;
+<programlisting>
+SELECT * FROM a, b, c WHERE a.id = b.id AND b.ref = c.id;
SELECT * FROM a CROSS JOIN b CROSS JOIN c WHERE a.id = b.id AND b.ref = c.id;
SELECT * FROM a JOIN (b JOIN c ON (b.ref = c.id)) ON (a.id = b.id);
- </programlisting>
- the second and third take less time to plan than the first. This effect
+</programlisting>
+ but the second and third take less time to plan than the first. This effect
is not worth worrying about for only three tables, but it can be a
lifesaver with many tables.
</para>
<para>
You do not need to constrain the join order completely in order to
- cut search time, because it's OK to use JOIN operators in a plain
- FROM list. For example,
- <programlisting>
+ cut search time, because it's OK to use <literal>JOIN</> operators in a plain
+ <literal>FROM</> list. For example,
+<programlisting>
SELECT * FROM a CROSS JOIN b, c, d, e WHERE ...;
- </programlisting>
+</programlisting>
forces the planner to join A to B before joining them to other tables,
but doesn't constrain its choices otherwise. In this example, the
number of possible join orders is reduced by a factor of 5.
If you have a mix of outer and inner joins in a complex query, you
might not want to constrain the planner's search for a good ordering
of inner joins inside an outer join. You can't do that directly in the
- JOIN syntax, but you can get around the syntactic limitation by using
+ <literal>JOIN</> syntax, but you can get around the syntactic limitation by using
subselects. For example,
- <programlisting>
+<programlisting>
SELECT * FROM d LEFT JOIN
(SELECT * FROM a, b, c WHERE ...) AS ss
ON (...);
- </programlisting>
+</programlisting>
Here, joining D must be the last step in the query plan, but the
- planner is free to consider various join orders for A,B,C.
+ planner is free to consider various join orders for A, B, C.
</para>
<para>
Constraining the planner's search in this way is a useful technique
both for reducing planning time and for directing the planner to a
good query plan. If the planner chooses a bad join order by default,
- you can force it to choose a better order via JOIN syntax --- assuming
+ you can force it to choose a better order via <literal>JOIN</> syntax --- assuming
that you know of a better order, that is. Experimentation is recommended.
</para>
</sect1>
If you allow each insertion to be committed separately,
<productname>PostgreSQL</productname> is doing a lot of work for each
record added.
+ An additional benefit of doing all insertions in one transaction
+ is that if the insertion of one record were to fail then the
+ insertion of all records inserted up to that point would be rolled
+ back, so you won't be stuck with partially loaded data.
</para>
</sect2>
</sect2>
<sect2 id="populate-analyze">
- <title>ANALYZE Afterwards</title>
+ <title>Run ANALYZE Afterwards</title>
<para>
It's a good idea to run <command>ANALYZE</command> or <command>VACUUM
-<!-- $Header: /cvsroot/pgsql/doc/src/sgml/queries.sgml,v 1.18 2002/10/20 05:05:46 tgl Exp $ -->
+<!-- $Header: /cvsroot/pgsql/doc/src/sgml/queries.sgml,v 1.18.2.1 2002/11/10 12:45:42 petere Exp $ -->
<chapter id="queries">
<title>Queries</title>
order in which the columns are listed does not matter. The
purpose is to reduce each group of rows sharing common values into
one group row that is representative of all rows in the group.
- This is done to eliminate redundancy in the output and/or obtain
+ This is done to eliminate redundancy in the output and/or compute
aggregates that apply to these groups. For instance:
<screen>
<prompt>=></> <userinput>SELECT * FROM test1;</>
In the second query, we could not have written <literal>SELECT *
FROM test1 GROUP BY x</literal>, because there is no single value
for the column <literal>y</> that could be associated with each
- group. In general, if a table is grouped, columns that are not
+ group. The grouped-by columns can be referenced in the select list since
+ they have a known constant value per group.
+ </para>
+
+ <para>
+ In general, if a table is grouped, columns that are not
used in the grouping cannot be referenced except in aggregate
expressions. An example with aggregate expressions is:
<screen>
linkend="functions-aggregate">.
</para>
- <para>
- The grouped-by columns can be referenced in the select list since
- they have a known constant value per group.
- </para>
-
<tip>
<para>
Grouping without aggregate expressions effectively calculates the
in the <literal>GROUP BY</> clause since they are referenced in
the query select list. (Depending on how exactly the products
table is set up, name and price may be fully dependent on the
- product ID, so the additional groups could theoretically be
+ product ID, so the additional groupings could theoretically be
unnecessary, but this is not implemented yet.) The column
<literal>s.units</> does not have to be in the <literal>GROUP
BY</> list since it is only used in an aggregate expression
</para>
<sect2 id="queries-select-list-items">
- <title>Select List Items</title>
+ <title>Select-List Items</title>
<para>
The simplest kind of select list is <literal>*</literal> which
<!--
-$Header: /cvsroot/pgsql/doc/src/sgml/syntax.sgml,v 1.72 2002/10/24 17:48:54 petere Exp $
+$Header: /cvsroot/pgsql/doc/src/sgml/syntax.sgml,v 1.72.2.1 2002/11/10 12:45:42 petere Exp $
-->
<chapter id="sql-syntax">
characters of an identifier; longer names can be written in
commands, but they will be truncated. By default,
<symbol>NAMEDATALEN</symbol> is 64 so the maximum identifier length
- is 63 (but at the time the system is built,
+ is 63 (but at the time PostgreSQL is built,
<symbol>NAMEDATALEN</symbol> can be changed in
<filename>src/include/postgres_ext.h</filename>).
</para>
<para>
Quoted identifiers can contain any character other than a double
- quote itself. This allows constructing table or column names that
- would otherwise not be possible, such as ones containing spaces or
+ quote itself. To include a double quote, write two double quotes.
+ This allows constructing table or column names that would
+ otherwise not be possible, such as ones containing spaces or
ampersands. The length limitation still applies.
</para>
SELECT 'foo' 'bar';
</programlisting>
is not valid syntax. (This slightly bizarre behavior is specified
- by <acronym>SQL9x</acronym>; <productname>PostgreSQL</productname> is
+ by <acronym>SQL</acronym>; <productname>PostgreSQL</productname> is
following the standard.)
</para>
</sect3>
Alternatively, bit-string constants can be specified in hexadecimal
notation, using a leading <literal>X</literal> (upper or lower case),
e.g., <literal>X'1FF'</literal>. This notation is equivalent to
- a bit-string constant with four binary digits for each hex digit.
+ a bit-string constant with four binary digits for each hexadecimal digit.
</para>
<para>
decimal point, if one is used. At least one digit must follow the
exponent marker (<literal>e</literal>), if one is present.
There may not be any spaces or other characters embedded in the
- constant. Notice that any leading plus or minus sign is not actually
+ constant. Note that any leading plus or minus sign is not actually
considered part of the constant; it is an operator applied to the
constant.
</para>
</indexterm>
<para>
- The precedence and associativity of the operators is hard-wired
- into the parser. Most operators have the same precedence and are
- left-associative. This may lead to non-intuitive behavior; for
- example the Boolean operators <literal><</> and <literal>></> have a different
- precedence than the Boolean operators <literal><=</> and <literal>>=</>. Also,
- you will sometimes need to add parentheses when using combinations
- of binary and unary operators. For instance
+ <xref linkend="sql-precedence-table"> shows the precedence and
+ associativity of the operators in PostgreSQL. Most operators have
+ the same precedence and are left-associative. The precedence and
+ associativity of the operators is hard-wired into the parser.
+ This may lead to non-intuitive behavior; for example the Boolean
+ operators <literal><</> and <literal>></> have a different
+ precedence than the Boolean operators <literal><=</> and
+ <literal>>=</>. Also, you will sometimes need to add
+ parentheses when using combinations of binary and unary operators.
+ For instance
<programlisting>
SELECT 5 ! - 6;
</programlisting>
This is the price one pays for extensibility.
</para>
- <table tocentry="1">
+ <table id="sql-precedence-table">
<title>Operator Precedence (decreasing)</title>
<tgroup cols="3">
SELECT 3 OPERATOR(pg_catalog.+) 4;
</programlisting>
the <literal>OPERATOR</> construct is taken to have the default precedence
- shown above for <quote>any other</> operator. This is true no matter
+ shown in <xref linkend="sql-precedence-table"> for <quote>any other</> operator. This is true no matter
which specific operator name appears inside <literal>OPERATOR()</>.
</para>
</sect2>
</listitem>
<listitem>
-<synopsis>( <replaceable>expression</replaceable> )</synopsis>
<para>
- Parentheses are used to group subexpressions and override precedence.
+ Another value expression in parentheses, useful to group subexpressions and override precedence.
</para>
</listitem>
</itemizedlist>
<title>Column References</title>
<para>
- A column can be referenced in the form:
+ A column can be referenced in the form
<synopsis>
-<replaceable>correlation</replaceable>.<replaceable>columnname</replaceable> `['<replaceable>subscript</replaceable>`]'
+<replaceable>correlation</replaceable>.<replaceable>columnname</replaceable>
</synopsis>
+ or
+<synopsis>
+<replaceable>correlation</replaceable>.<replaceable>columnname</replaceable>[<replaceable>subscript</replaceable>]
+</synopsis>
+ (Here, the brackets <literal>[ ]</literal> are meant to appear literally.)
+ </para>
+ <para>
<replaceable>correlation</replaceable> is the name of a
table (possibly qualified), or an alias for a table defined by means of a
- FROM clause, or
+ <literal>FROM</literal> clause, or
the key words <literal>NEW</literal> or <literal>OLD</literal>.
- (NEW and OLD can only appear in rules,
+ (<literal>NEW</literal> and <literal>OLD</literal> can only appear in rewrite rules,
while other correlation names can be used in any SQL statement.)
The correlation name and separating dot may be omitted if the column name
- is unique
- across all the tables being used in the current query. If
- <replaceable>column</replaceable> is of an array type, then the
+ is unique across all the tables being used in the current query. (See also <xref linkend="queries">.)
+ </para>
+
+ <para>
+ If <replaceable>column</replaceable> is of an array type, then the
optional <replaceable>subscript</replaceable> selects a specific
element or elements in the array. If no subscript is provided, then the
whole array is selected. (See <xref linkend="arrays"> for more about
<function>dept</function>, as
<programlisting>
-CREATE FUNCTION dept (text) RETURNS dept
- AS 'SELECT * FROM dept WHERE name = $1'
- LANGUAGE SQL;
+CREATE FUNCTION dept(text) RETURNS dept
+ AS 'SELECT * FROM dept WHERE name = $1'
+ LANGUAGE SQL;
</programlisting>
Here the <literal>$1</literal> will be replaced by the first
keywords <token>AND</token>, <token>OR</token>, and
<token>NOT</token>, or is a qualified operator name
<synopsis>
- <literal>OPERATOR(</><replaceable>schema</><literal>.</><replaceable>operatorname</><literal>)</>
+<literal>OPERATOR(</><replaceable>schema</><literal>.</><replaceable>operatorname</><literal>)</>
</synopsis>
Which particular operators exist and whether
they are unary or binary depends on what operators have been
output value, such as the sum or average of the inputs. The
syntax of an aggregate expression is one of the following:
- <simplelist>
- <member><replaceable>aggregate_name</replaceable> (<replaceable>expression</replaceable>)</member>
- <member><replaceable>aggregate_name</replaceable> (ALL <replaceable>expression</replaceable>)</member>
- <member><replaceable>aggregate_name</replaceable> (DISTINCT <replaceable>expression</replaceable>)</member>
- <member><replaceable>aggregate_name</replaceable> ( * )</member>
- </simplelist>
+<synopsis>
+<replaceable>aggregate_name</replaceable> (<replaceable>expression</replaceable>)
+<replaceable>aggregate_name</replaceable> (ALL <replaceable>expression</replaceable>)
+<replaceable>aggregate_name</replaceable> (DISTINCT <replaceable>expression</replaceable>)
+<replaceable>aggregate_name</replaceable> ( * )
+</synopsis>
where <replaceable>aggregate_name</replaceable> is a previously
defined aggregate (possibly a qualified name), and
CAST ( <replaceable>expression</replaceable> AS <replaceable>type</replaceable> )
<replaceable>expression</replaceable>::<replaceable>type</replaceable>
</synopsis>
- The <literal>CAST</> syntax conforms to SQL92; the syntax with
+ The <literal>CAST</> syntax conforms to SQL; the syntax with
<literal>::</literal> is historical <productname>PostgreSQL</productname>
usage.
</para>
to the type that a value expression must produce (for example, when it is
assigned to a table column); the system will automatically apply a
type cast in such cases. However, automatic casting is only done for
- cast functions that are marked <quote>OK to apply implicitly</>
- in the system catalogs. Other cast functions must be invoked with
+ casts that are marked <quote>OK to apply implicitly</>
+ in the system catalogs. Other casts must be invoked with
explicit casting syntax. This restriction is intended to prevent
surprising conversions from being applied silently.
</para>
double-quoted, because of syntactic conflicts. Therefore, the use of
the function-like cast syntax leads to inconsistencies and should
probably be avoided in new applications.
+
+ (The function-like syntax is in fact just a function call. When
+ one of the two standard cast syntaxes is used to do a run-time
+ conversion, it will internally invoke a registered function to
+ perform the conversion. By convention, these conversion functions
+ have the same name as their output type, but this is not something
+ that a portable application should rely on.)
</para>
</sect2>
<para>
A scalar subquery is an ordinary
- <command>SELECT</command> in parentheses that returns exactly one
- row with one column. The <command>SELECT</command> query is executed
+ <command>SELECT</command> query in parentheses that returns exactly one
+ row with one column. (See <xref linkend="queries"> for information about writing queries.)
+ The <command>SELECT</command> query is executed
and the single returned value is used in the surrounding value expression.
It is an error to use a query that
returns more than one row or more than one column as a scalar subquery.
state:
<programlisting>
SELECT name, (SELECT max(pop) FROM cities WHERE cities.state = states.name)
-FROM states;
+ FROM states;
</programlisting>
</para>
</sect2>
<para>
As a consequence, it is unwise to use functions with side effects
as part of complex expressions. It is particularly dangerous to
- rely on side effects or evaluation order in WHERE and HAVING clauses,
+ rely on side effects or evaluation order in <literal>WHERE</> and <literal>HAVING</> clauses,
since those clauses are extensively reprocessed as part of
developing an execution plan. Boolean
- expressions (AND/OR/NOT combinations) in those clauses may be reorganized
+ expressions (<literal>AND</>/<literal>OR</>/<literal>NOT</> combinations) in those clauses may be reorganized
in any manner allowed by the laws of Boolean algebra.
</para>
<para>
- When it is essential to force evaluation order, a CASE construct may
- be used. For example, this is an untrustworthy way of trying to
- avoid division by zero in a WHERE clause:
+ When it is essential to force evaluation order, a <literal>CASE</>
+ construct (see <xref linkend="functions-conditional">) may be
+ used. For example, this is an untrustworthy way of trying to
+ avoid division by zero in a <literal>WHERE</> clause:
<programlisting>
SELECT ... WHERE x <> 0 AND y/x > 1.5;
</programlisting>
- but this is safe:
+ But this is safe:
<programlisting>
SELECT ... WHERE CASE WHEN x <> 0 THEN y/x > 1.5 ELSE false END;
</programlisting>
- A CASE construct used in this fashion will defeat optimization attempts,
+ A <literal>CASE</> construct used in this fashion will defeat optimization attempts,
so it should only be done when necessary.
</para>
</sect2>
<chapter Id="typeconv">
<title>Type Conversion</title>
- <sect1 id="typeconv-intro">
- <title>Introduction</title>
-
<para>
<acronym>SQL</acronym> queries can, intentionally or not, require
mixing of different data types in the same expression.
</para>
<para>
-The <citetitle>Programmer's Guide</citetitle> has more details on the exact algorithms used for
+The &cite-programmer; has more details on the exact algorithms used for
implicit type conversion and coercion.
</para>
- </sect1>
<sect1 id="typeconv-overview">
<title>Overview</title>
<acronym>SQL</acronym> is a strongly typed language. That is, every data item
has an associated data type which determines its behavior and allowed usage.
<productname>PostgreSQL</productname> has an extensible type system that is
-much more general and flexible than other <acronym>RDBMS</acronym> implementations.
+much more general and flexible than other <acronym>SQL</acronym> implementations.
Hence, most type conversion behavior in <productname>PostgreSQL</productname>
should be governed by general rules rather than by <foreignphrase>ad hoc</> heuristics, to allow
mixed-type expressions to be meaningful even with user-defined types.
</para>
<para>
-The <productname>PostgreSQL</productname> parser uses the convention that all
-type conversion functions take a single argument of the source type and are
-named with the same name as the target type. Any function meeting these
-criteria is considered to be a valid conversion function, and may be used
-by the parser as such. This simple assumption gives the parser the power
-to explore type conversion possibilities without hardcoding, allowing
-extended user-defined types to use these same features transparently.
+The system catalogs store information about which conversions, called
+<firstterm>casts</firstterm>, between data types are valid, and how to
+perform those conversions. Additional casts can be added by the user
+with the <command>CREATE CAST</command> command. (This is usually
+done in conjunction with defining new data types. The set of casts
+between the built-in types has been carefully crafted and should not
+be altered.)
</para>
<para>
<para>
All type conversion rules are designed with several principles in mind:
-<itemizedlist mark="bullet" spacing="compact">
+<itemizedlist>
<listitem>
<para>
Implicit conversions should never have surprising or unpredictable outcomes.
<!--
-$Header: /cvsroot/pgsql/doc/src/sgml/Attic/user.sgml,v 1.33 2002/10/24 17:48:54 petere Exp $
+$Header: /cvsroot/pgsql/doc/src/sgml/Attic/user.sgml,v 1.33.2.1 2002/11/10 12:45:43 petere Exp $
-->
<book id="user">
database, and how to query it. The middle part lists the
available data types and functions for use in SQL data commands.
The rest of the book treats several aspects that are important for
- tuning a database for optimial performance.
+ tuning a database for optimal performance.
</para>
<para>