postgresql/doc/src/sgml/datatype.sgml

3238 lines
105 KiB
Plaintext

<!--
$PostgreSQL: pgsql/doc/src/sgml/datatype.sgml,v 1.132 2003/11/29 19:51:36 pgsql Exp $
-->
<chapter id="datatype">
<title id="datatype-title">Data Types</title>
<indexterm zone="datatype">
<primary>data type</primary>
</indexterm>
<indexterm>
<primary>type</primary>
<see>data type</see>
</indexterm>
<para>
<productname>PostgreSQL</productname> has a rich set of native data
types available to users.
Users may add new types to <productname>PostgreSQL</productname> using the
<command>CREATE TYPE</command> command.
</para>
<para>
<xref linkend="datatype-table"> shows all built-in general-purpose data types.
Most of the alternative names
listed in the
<quote>Aliases</quote> column are the names used internally by
<productname>PostgreSQL</productname> for historical reasons. In
addition, some internally used or deprecated types are available,
but they are not listed here.
</para>
<table id="datatype-table">
<title>Data Types</title>
<tgroup cols="3">
<thead>
<row>
<entry>Name</entry>
<entry>Aliases</entry>
<entry>Description</entry>
</row>
</thead>
<tbody>
<row>
<entry><type>bigint</type></entry>
<entry><type>int8</type></entry>
<entry>signed eight-byte integer</entry>
</row>
<row>
<entry><type>bigserial</type></entry>
<entry><type>serial8</type></entry>
<entry>autoincrementing eight-byte integer</entry>
</row>
<row>
<entry><type>bit</type></entry>
<entry></entry>
<entry>fixed-length bit string</entry>
</row>
<row>
<entry><type>bit varying(<replaceable>n</replaceable>)</type></entry>
<entry><type>varbit(<replaceable>n</replaceable>)</type></entry>
<entry>variable-length bit string</entry>
</row>
<row>
<entry><type>boolean</type></entry>
<entry><type>bool</type></entry>
<entry>logical Boolean (true/false)</entry>
</row>
<row>
<entry><type>box</type></entry>
<entry></entry>
<entry>rectangular box in the plane</entry>
</row>
<row>
<entry><type>bytea</type></entry>
<entry></entry>
<entry>binary data</entry>
</row>
<row>
<entry><type>character varying(<replaceable>n</replaceable>)</type></entry>
<entry><type>varchar(<replaceable>n</replaceable>)</type></entry>
<entry>variable-length character string</entry>
</row>
<row>
<entry><type>character(<replaceable>n</replaceable>)</type></entry>
<entry><type>char(<replaceable>n</replaceable>)</type></entry>
<entry>fixed-length character string</entry>
</row>
<row>
<entry><type>cidr</type></entry>
<entry></entry>
<entry>IPv4 or IPv6 network address</entry>
</row>
<row>
<entry><type>circle</type></entry>
<entry></entry>
<entry>circle in the plane</entry>
</row>
<row>
<entry><type>date</type></entry>
<entry></entry>
<entry>calendar date (year, month, day)</entry>
</row>
<row>
<entry><type>double precision</type></entry>
<entry><type>float8</type></entry>
<entry>double precision floating-point number</entry>
</row>
<row>
<entry><type>inet</type></entry>
<entry></entry>
<entry>IPv4 or IPv6 host address</entry>
</row>
<row>
<entry><type>integer</type></entry>
<entry><type>int</type>, <type>int4</type></entry>
<entry>signed four-byte integer</entry>
</row>
<row>
<entry><type>interval(<replaceable>p</replaceable>)</type></entry>
<entry></entry>
<entry>time span</entry>
</row>
<row>
<entry><type>line</type></entry>
<entry></entry>
<entry>infinite line in the plane (not fully implemented)</entry>
</row>
<row>
<entry><type>lseg</type></entry>
<entry></entry>
<entry>line segment in the plane</entry>
</row>
<row>
<entry><type>macaddr</type></entry>
<entry></entry>
<entry>MAC address</entry>
</row>
<row>
<entry><type>money</type></entry>
<entry></entry>
<entry>currency amount</entry>
</row>
<row>
<entry><type>numeric [ (<replaceable>p</replaceable>,
<replaceable>s</replaceable>) ]</type></entry>
<entry><type>decimal [ (<replaceable>p</replaceable>,
<replaceable>s</replaceable>) ]</type></entry>
<entry>exact numeric with selectable precision</entry>
</row>
<row>
<entry><type>path</type></entry>
<entry></entry>
<entry>open and closed geometric path in the plane</entry>
</row>
<row>
<entry><type>point</type></entry>
<entry></entry>
<entry>geometric point in the plane</entry>
</row>
<row>
<entry><type>polygon</type></entry>
<entry></entry>
<entry>closed geometric path in the plane</entry>
</row>
<row>
<entry><type>real</type></entry>
<entry><type>float4</type></entry>
<entry>single precision floating-point number</entry>
</row>
<row>
<entry><type>smallint</type></entry>
<entry><type>int2</type></entry>
<entry>signed two-byte integer</entry>
</row>
<row>
<entry><type>serial</type></entry>
<entry><type>serial4</type></entry>
<entry>autoincrementing four-byte integer</entry>
</row>
<row>
<entry><type>text</type></entry>
<entry></entry>
<entry>variable-length character string</entry>
</row>
<row>
<entry><type>time [ (<replaceable>p</replaceable>) ] [ without time zone ]</type></entry>
<entry></entry>
<entry>time of day</entry>
</row>
<row>
<entry><type>time [ (<replaceable>p</replaceable>) ] with time zone</type></entry>
<entry><type>timetz</type></entry>
<entry>time of day, including time zone</entry>
</row>
<row>
<entry><type>timestamp [ (<replaceable>p</replaceable>) ] without time zone</type></entry>
<entry><type>timestamp</type></entry>
<entry>date and time</entry>
</row>
<row>
<entry><type>timestamp [ (<replaceable>p</replaceable>) ] [ with time zone ]</type></entry>
<entry><type>timestamptz</type></entry>
<entry>date and time, including time zone</entry>
</row>
</tbody>
</tgroup>
</table>
<note>
<title>Compatibility</title>
<para>
The following types (or spellings thereof) are specified by
<acronym>SQL</acronym>: <type>bit</type>, <type>bit
varying</type>, <type>boolean</type>, <type>char</type>,
<type>character varying</type>, <type>character</type>,
<type>varchar</type>, <type>date</type>, <type>double
precision</type>, <type>integer</type>, <type>interval</type>,
<type>numeric</type>, <type>decimal</type>, <type>real</type>,
<type>smallint</type>, <type>time</type> (with or without time zone),
<type>timestamp</type> (with or without time zone).
</para>
</note>
<para>
Each data type has an external representation determined by its input
and output functions. Many of the built-in types have
obvious external formats. However, several types are either unique
to <productname>PostgreSQL</productname>, such as open and closed
paths, or have several possibilities for formats, such as the date
and time types.
Some of the input and output functions are not invertible. That is,
the result of an output function may lose accuracy when compared to
the original input.
</para>
<para>
Some of the operators and functions (e.g.,
addition and multiplication) do not perform run-time error-checking in the
interests of improving execution speed.
On some systems, for example, the numeric operators for some data types may
silently cause underflow or overflow.
</para>
<sect1 id="datatype-numeric">
<title>Numeric Types</title>
<indexterm zone="datatype-numeric">
<primary>data type</primary>
<secondary>numeric</secondary>
</indexterm>
<para>
Numeric types consist of two-, four-, and eight-byte integers,
four- and eight-byte floating-point numbers, and fixed-precision
decimals. <xref linkend="datatype-numeric-table"> lists the
available types.
</para>
<table id="datatype-numeric-table">
<title>Numeric Types</title>
<tgroup cols="4">
<thead>
<row>
<entry>Name</entry>
<entry>Storage Size</entry>
<entry>Description</entry>
<entry>Range</entry>
</row>
</thead>
<tbody>
<row>
<entry><type>smallint</></entry>
<entry>2 bytes</entry>
<entry>small-range integer</entry>
<entry>-32768 to +32767</entry>
</row>
<row>
<entry><type>integer</></entry>
<entry>4 bytes</entry>
<entry>usual choice for integer</entry>
<entry>-2147483648 to +2147483647</entry>
</row>
<row>
<entry><type>bigint</></entry>
<entry>8 bytes</entry>
<entry>large-range integer</entry>
<entry>-9223372036854775808 to 9223372036854775807</entry>
</row>
<row>
<entry><type>decimal</></entry>
<entry>variable</entry>
<entry>user-specified precision, exact</entry>
<entry>no limit</entry>
</row>
<row>
<entry><type>numeric</></entry>
<entry>variable</entry>
<entry>user-specified precision, exact</entry>
<entry>no limit</entry>
</row>
<row>
<entry><type>real</></entry>
<entry>4 bytes</entry>
<entry>variable-precision, inexact</entry>
<entry>6 decimal digits precision</entry>
</row>
<row>
<entry><type>double precision</></entry>
<entry>8 bytes</entry>
<entry>variable-precision, inexact</entry>
<entry>15 decimal digits precision</entry>
</row>
<row>
<entry><type>serial</></entry>
<entry>4 bytes</entry>
<entry>autoincrementing integer</entry>
<entry>1 to 2147483647</entry>
</row>
<row>
<entry><type>bigserial</type></entry>
<entry>8 bytes</entry>
<entry>large autoincrementing integer</entry>
<entry>1 to 9223372036854775807</entry>
</row>
</tbody>
</tgroup>
</table>
<para>
The syntax of constants for the numeric types is described in
<xref linkend="sql-syntax-constants">. The numeric types have a
full set of corresponding arithmetic operators and
functions. Refer to <xref linkend="functions"> for more
information. The following sections describe the types in detail.
</para>
<sect2 id="datatype-int">
<title>Integer Types</title>
<indexterm zone="datatype-int">
<primary>integer</primary>
</indexterm>
<indexterm zone="datatype-int">
<primary>smallint</primary>
</indexterm>
<indexterm zone="datatype-int">
<primary>bigint</primary>
</indexterm>
<indexterm>
<primary>int4</primary>
<see>integer</see>
</indexterm>
<indexterm>
<primary>int2</primary>
<see>smallint</see>
</indexterm>
<indexterm>
<primary>int8</primary>
<see>bigint</see>
</indexterm>
<para>
The types <type>smallint</type>, <type>integer</type>, and
<type>bigint</type> store whole numbers, that is, numbers without
fractional components, of various ranges. Attempts to store
values outside of the allowed range will result in an error.
</para>
<para>
The type <type>integer</type> is the usual choice, as it offers
the best balance between range, storage size, and performance.
The <type>smallint</type> type is generally only used if disk
space is at a premium. The <type>bigint</type> type should only
be used if the <type>integer</type> range is not sufficient,
because the latter is definitely faster.
</para>
<para>
The <type>bigint</type> type may not function correctly on all
platforms, since it relies on compiler support for eight-byte
integers. On a machine without such support, <type>bigint</type>
acts the same as <type>integer</type> (but still takes up eight
bytes of storage). However, we are not aware of any reasonable
platform where this is actually the case.
</para>
<para>
<acronym>SQL</acronym> only specifies the integer types
<type>integer</type> (or <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 <acronym>SQL</acronym> database systems.
</para>
<note>
<para>
If you have a column of type <type>smallint</type> or
<type>bigint</type> with an index, you may encounter problems
getting the system to use that index. For instance, a clause of
the form
<programlisting>
... WHERE smallint_column = 42
</programlisting>
will not use an index, because the system assigns type
<type>integer</type> to the constant 42, and
<productname>PostgreSQL</productname> currently
cannot use an index when two different data types are involved. A
workaround is to single-quote the constant, thus:
<programlisting>
... WHERE smallint_column = '42'
</programlisting>
This will cause the system to delay type resolution and will
assign the right type to the constant.
</para>
</note>
</sect2>
<sect2 id="datatype-numeric-decimal">
<title>Arbitrary Precision Numbers</title>
<indexterm zone="datatype-numeric-decimal">
<primary>numeric (data type)</primary>
</indexterm>
<indexterm>
<primary>decimal</primary>
<see>numeric</see>
</indexterm>
<para>
The type <type>numeric</type> can store numbers with up to 1000
digits of precision and perform calculations exactly. It is
especially recommended for storing monetary amounts and other
quantities where exactness is required. However, the
<type>numeric</type> type is very slow compared to the
floating-point types described in the next section.
</para>
<para>
In what follows we use these terms: The
<firstterm>scale</firstterm> of a <type>numeric</type> is the
count of decimal digits in the fractional part, to the right of
the decimal point. The <firstterm>precision</firstterm> of a
<type>numeric</type> is the total count of significant digits in
the whole number, that is, the number of digits to both sides of
the decimal point. So the number 23.5141 has a precision of 6
and a scale of 4. Integers can be considered to have a scale of
zero.
</para>
<para>
Both the precision and the scale of the numeric type can be
configured. To declare a column of type <type>numeric</type> use
the syntax
<programlisting>
NUMERIC(<replaceable>precision</replaceable>, <replaceable>scale</replaceable>)
</programlisting>
The precision must be positive, the scale zero or positive.
Alternatively,
<programlisting>
NUMERIC(<replaceable>precision</replaceable>)
</programlisting>
selects a scale of 0. Specifying
<programlisting>
NUMERIC
</programlisting>
without any precision or scale creates a column in which numeric
values of any precision and scale can be stored, up to the
implementation limit on precision. A column of this kind will
not coerce input values to any particular scale, whereas
<type>numeric</type> columns with a declared scale will coerce
input values to that scale. (The <acronym>SQL</acronym> standard
requires a default scale of 0, i.e., coercion to integer
precision. We find this a bit useless. If you're concerned
about portability, always specify the precision and scale
explicitly.)
</para>
<para>
If the precision or scale of a value is greater than the declared
precision or scale of a column, the system will attempt to round
the value. If the value cannot be rounded so as to satisfy the
declared limits, an error is raised.
</para>
<para>
The types <type>decimal</type> and <type>numeric</type> are
equivalent. Both types are part of the <acronym>SQL</acronym>
standard.
</para>
</sect2>
<sect2 id="datatype-float">
<title>Floating-Point Types</title>
<indexterm zone="datatype-float">
<primary>real</primary>
</indexterm>
<indexterm zone="datatype-float">
<primary>double precision</primary>
</indexterm>
<indexterm>
<primary>float4</primary>
<see>real</see>
</indexterm>
<indexterm>
<primary>float8</primary>
<see>double precision</see>
</indexterm>
<indexterm zone="datatype-float">
<primary>floating point</primary>
</indexterm>
<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> 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>
Inexact means that some values cannot be converted exactly to the
internal format and are stored as approximations, so that storing
and printing back out a value may show slight discrepancies.
Managing these errors and how they propagate through calculations
is the subject of an entire branch of mathematics and computer
science and will not be discussed further here, except for the
following points:
<itemizedlist>
<listitem>
<para>
If you require exact storage and calculations (such as for
monetary amounts), use the <type>numeric</type> type instead.
</para>
</listitem>
<listitem>
<para>
If you want to do complicated calculations with these types
for anything important, especially if you rely on certain
behavior in boundary cases (infinity, underflow), you should
evaluate the implementation carefully.
</para>
</listitem>
<listitem>
<para>
Comparing two floating-point values for equality may or may
not work as expected.
</para>
</listitem>
</itemizedlist>
</para>
<para>
On most platforms, the <type>real</type> type has a range of at least
1E-37 to 1E+37 with a precision of at least 6 decimal digits. The
<type>double precision</type> type typically has a range of around
1E-307 to 1E+308 with a precision of at least 15 digits. Values that
are too large or too small will cause an error. Rounding may
take place if the precision of an input number is too high.
Numbers too close to zero that are not representable as distinct
from zero will cause an underflow error.
</para>
<para>
<productname>PostgreSQL</productname> also supports the SQL-standard
notations <type>float</type> and
<type>float(<replaceable>p</replaceable>)</type> for specifying
inexact numeric types. Here, <replaceable>p</replaceable> specifies
the minimum acceptable precision in binary digits.
<productname>PostgreSQL</productname> accepts
<type>float(1)</type> to <type>float(24)</type> as selecting the
<type>real</type> type, while
<type>float(25)</type> to <type>float(53)</type> select
<type>double precision</type>. Values of <replaceable>p</replaceable>
outside the allowed range draw an error.
<type>float</type> with no precision specified is taken to mean
<type>double precision</type>.
</para>
<note>
<para>
Prior to <productname>PostgreSQL</productname> 7.4, the precision in
<type>float(<replaceable>p</replaceable>)</type> was taken to mean
so many decimal digits. This has been corrected to match the SQL
standard, which specifies that the precision is measured in binary
digits. The assumption that <type>real</type> and
<type>double precision</type> have exactly 24 and 53 bits in the
mantissa respectively is correct for IEEE-standard floating point
implementations. On non-IEEE platforms it may be off a little, but
for simplicity the same ranges of <replaceable>p</replaceable> are used
on all platforms.
</para>
</note>
</sect2>
<sect2 id="datatype-serial">
<title>Serial Types</title>
<indexterm zone="datatype-serial">
<primary>serial</primary>
</indexterm>
<indexterm zone="datatype-serial">
<primary>bigserial</primary>
</indexterm>
<indexterm zone="datatype-serial">
<primary>serial4</primary>
</indexterm>
<indexterm zone="datatype-serial">
<primary>serial8</primary>
</indexterm>
<indexterm>
<primary>auto-increment</primary>
<see>serial</see>
</indexterm>
<indexterm>
<primary>sequence</primary>
<secondary>and serial type</secondary>
</indexterm>
<para>
The data types <type>serial</type> and <type>bigserial</type>
are not true types, but merely
a notational convenience for setting up unique identifier columns
(similar to the <literal>AUTO_INCREMENT</literal> property
supported by some other databases). In the current
implementation, specifying
<programlisting>
CREATE TABLE <replaceable class="parameter">tablename</replaceable> (
<replaceable class="parameter">colname</replaceable> SERIAL
);
</programlisting>
is equivalent to specifying:
<programlisting>
CREATE SEQUENCE <replaceable class="parameter">tablename</replaceable>_<replaceable class="parameter">colname</replaceable>_seq;
CREATE TABLE <replaceable class="parameter">tablename</replaceable> (
<replaceable class="parameter">colname</replaceable> integer DEFAULT nextval('<replaceable class="parameter">tablename</replaceable>_<replaceable class="parameter">colname</replaceable>_seq') NOT NULL
);
</programlisting>
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
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
not automatic.
</para>
<note>
<para>
Prior to <productname>PostgreSQL</productname> 7.3, <type>serial</type>
implied <literal>UNIQUE</literal>. This is no longer automatic. If
you wish a serial column to be in a unique constraint or a
primary key, it must now be specified, same as with
any other data type.
</para>
</note>
<para>
To insert the next value of the sequence into the <type>serial</type>
column, specify that the <type>serial</type>
column should be assigned its default value. This can be done
either by excluding the column from the list of columns in
the <command>INSERT</command> statement, or through the use of
the <literal>DEFAULT</literal> key word.
</para>
<para>
The type names <type>serial</type> and <type>serial4</type> are
equivalent: both create <type>integer</type> columns. The type
names <type>bigserial</type> and <type>serial8</type> work just
the same way, except that they create a <type>bigint</type>
column. <type>bigserial</type> should be used if you anticipate
the use of more than 2<superscript>31</> identifiers over the
lifetime of the table.
</para>
<para>
The sequence created for a <type>serial</type> column is
automatically dropped when the owning column is dropped, and
cannot be dropped otherwise. (This was not true in
<productname>PostgreSQL</productname> releases before 7.3. Note
that this automatic drop linkage will not occur for a sequence
created by reloading a dump from a pre-7.3 database; the dump
file does not contain the information needed to establish the
dependency link.) Furthermore, this dependency between sequence
and column is made only for the <type>serial</> column itself; if
any other columns reference the sequence (perhaps by manually
calling the <function>nextval</> function), they will be broken
if the sequence is removed. Using a <type>serial</> column's sequence
in such a fashion is considered bad form; if you wish to feed several
columns from the same sequence generator, create the sequence as an
independent object.
</para>
</sect2>
</sect1>
<sect1 id="datatype-money">
<title>Monetary Types</title>
<note>
<para>
The <type>money</type> type is deprecated. Use
<type>numeric</type> or <type>decimal</type> instead, in
combination with the <function>to_char</function> function.
</para>
</note>
<para>
The <type>money</type> type stores a currency amount with a fixed
fractional precision; see <xref
linkend="datatype-money-table">.
Input is accepted in a variety of formats, including integer and
floating-point literals, as well as <quote>typical</quote>
currency formatting, such as <literal>'$1,000.00'</literal>.
Output is generally in the latter form but depends on the locale.
</para>
<table id="datatype-money-table">
<title>Monetary Types</title>
<tgroup cols="4">
<thead>
<row>
<entry>Name</entry>
<entry>Storage Size</entry>
<entry>Description</entry>
<entry>Range</entry>
</row>
</thead>
<tbody>
<row>
<entry>money</entry>
<entry>4 bytes</entry>
<entry>currency amount</entry>
<entry>-21474836.48 to +21474836.47</entry>
</row>
</tbody>
</tgroup>
</table>
</sect1>
<sect1 id="datatype-character">
<title>Character Types</title>
<indexterm zone="datatype-character">
<primary>character string</primary>
<secondary>data types</secondary>
</indexterm>
<indexterm>
<primary>string</primary>
<see>character string</see>
</indexterm>
<indexterm zone="datatype-character">
<primary>character</primary>
</indexterm>
<indexterm zone="datatype-character">
<primary>character varying</primary>
</indexterm>
<indexterm zone="datatype-character">
<primary>text</primary>
</indexterm>
<indexterm zone="datatype-character">
<primary>char</primary>
</indexterm>
<indexterm zone="datatype-character">
<primary>varchar</primary>
</indexterm>
<table id="datatype-character-table">
<title>Character Types</title>
<tgroup cols="2">
<thead>
<row>
<entry>Name</entry>
<entry>Description</entry>
</row>
</thead>
<tbody>
<row>
<entry><type>character varying(<replaceable>n</>)</type>, <type>varchar(<replaceable>n</>)</type></entry>
<entry>variable-length with limit</entry>
</row>
<row>
<entry><type>character(<replaceable>n</>)</type>, <type>char(<replaceable>n</>)</type></entry>
<entry>fixed-length, blank padded</entry>
</row>
<row>
<entry><type>text</type></entry>
<entry>variable unlimited length</entry>
</row>
</tbody>
</tgroup>
</table>
<para>
<xref linkend="datatype-character-table"> shows the
general-purpose character types available in
<productname>PostgreSQL</productname>.
</para>
<para>
<acronym>SQL</acronym> defines two primary character types:
<type>character varying(<replaceable>n</>)</type> and
<type>character(<replaceable>n</>)</type>, where <replaceable>n</>
is a positive integer. Both of these types can store strings up to
<replaceable>n</> characters in length. An attempt to store a
longer string into a column of these types will result in an
error, unless the excess characters are all spaces, in which case
the string will be truncated to the maximum length. (This somewhat
bizarre exception is required by the <acronym>SQL</acronym>
standard.) If the string to be stored is shorter than the declared
length, values of type <type>character</type> will be space-padded;
values of type <type>character varying</type> will simply store the
shorter
string.
</para>
<para>
If one explicitly casts a value to <type>character
varying(<replaceable>n</>)</type> or
<type>character(<replaceable>n</>)</type>, then an over-length
value will be truncated to <replaceable>n</> characters without
raising an error. (This too is required by the
<acronym>SQL</acronym> standard.)
</para>
<note>
<para>
Prior to <productname>PostgreSQL</> 7.2, strings that were too long were
always truncated without raising an error, in either explicit or
implicit casting contexts.
</para>
</note>
<para>
The notations <type>varchar(<replaceable>n</>)</type> and
<type>char(<replaceable>n</>)</type> are aliases for <type>character
varying(<replaceable>n</>)</type> and
<type>character(<replaceable>n</>)</type>, respectively.
<type>character</type> without length specifier is equivalent to
<type>character(1)</type>; if <type>character varying</type> is used
without length specifier, the type accepts strings of any size. The
latter is a <productname>PostgreSQL</> extension.
</para>
<para>
In addition, <productname>PostgreSQL</productname> provides the
<type>text</type> type, which stores strings of any length.
Although the type <type>text</type> is not in the
<acronym>SQL</acronym> standard, several other SQL database
management systems have it as well.
</para>
<para>
The storage requirement for data of these types is 4 bytes plus the
actual string, and in case of <type>character</type> plus the
padding. Long strings are compressed by the system automatically, so
the physical requirement on disk may be less. Long values are also
stored in background tables so they do not interfere with rapid
access to the shorter column values. In any case, the longest
possible character string that can be stored is about 1 GB. (The
maximum value that will be allowed for <replaceable>n</> in the data
type declaration is less than that. It wouldn't be very useful to
change this because with multibyte character encodings the number of
characters and bytes can be quite different anyway. If you desire to
store long strings with no specific upper limit, use
<type>text</type> or <type>character varying</type> without a length
specifier, rather than making up an arbitrary length limit.)
</para>
<tip>
<para>
There are no performance differences between these three types,
apart from the increased storage size when using the blank-padded
type.
</para>
</tip>
<para>
Refer to <xref linkend="sql-syntax-strings"> for information about
the syntax of string literals, and to <xref linkend="functions">
for information about available operators and functions.
</para>
<example>
<title>Using the character types</title>
<programlisting>
CREATE TABLE test1 (a character(4));
INSERT INTO test1 VALUES ('ok');
SELECT a, char_length(a) FROM test1; -- <co id="co.datatype-char">
<computeroutput>
a | char_length
------+-------------
ok | 4
</computeroutput>
CREATE TABLE test2 (b varchar(5));
INSERT INTO test2 VALUES ('ok');
INSERT INTO test2 VALUES ('good ');
INSERT INTO test2 VALUES ('too long');
<computeroutput>ERROR: value too long for type character varying(5)</computeroutput>
INSERT INTO test2 VALUES ('too long'::varchar(5)); -- explicit truncation
SELECT b, char_length(b) FROM test2;
<computeroutput>
b | char_length
-------+-------------
ok | 2
good | 5
too l | 5
</computeroutput>
</programlisting>
<calloutlist>
<callout arearefs="co.datatype-char">
<para>
The <function>char_length</function> function is discussed in
<xref linkend="functions-string">.
</para>
</callout>
</calloutlist>
</example>
<para>
There are two other fixed-length character types in
<productname>PostgreSQL</productname>, shown in <xref
linkend="datatype-character-special-table">. The <type>name</type>
type exists <emphasis>only</emphasis> for storage of identifiers
in the internal system catalogs and is not intended for use by the general user. Its
length is currently defined as 64 bytes (63 usable characters plus
terminator) but should be referenced using the constant
<symbol>NAMEDATALEN</symbol>. The length is set at compile time (and
is therefore adjustable for special uses); the default maximum
length may change in a future release. The type <type>"char"</type>
(note the quotes) is different from <type>char(1)</type> in that it
only uses one byte of storage. It is internally used in the system
catalogs as a poor-man's enumeration type.
</para>
<table id="datatype-character-special-table">
<title>Special Character Types</title>
<tgroup cols="3">
<thead>
<row>
<entry>Name</entry>
<entry>Storage Size</entry>
<entry>Description</entry>
</row>
</thead>
<tbody>
<row>
<entry><type>"char"</type></entry>
<entry>1 byte</entry>
<entry>single-character internal type</entry>
</row>
<row>
<entry><type>name</type></entry>
<entry>64 bytes</entry>
<entry>internal type for object names</entry>
</row>
</tbody>
</tgroup>
</table>
</sect1>
<sect1 id="datatype-binary">
<title>Binary Data Types</title>
<indexterm zone="datatype-binary">
<primary>binary data</primary>
</indexterm>
<indexterm zone="datatype-binary">
<primary>bytea</primary>
</indexterm>
<para>
The <type>bytea</type> data type allows storage of binary strings;
see <xref linkend="datatype-binary-table">.
</para>
<table id="datatype-binary-table">
<title>Binary Data Types</title>
<tgroup cols="3">
<thead>
<row>
<entry>Name</entry>
<entry>Storage Size</entry>
<entry>Description</entry>
</row>
</thead>
<tbody>
<row>
<entry><type>bytea</type></entry>
<entry>4 bytes plus the actual binary string</entry>
<entry>variable-length binary string</entry>
</row>
</tbody>
</tgroup>
</table>
<para>
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 value zero 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>
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. <xref linkend="datatype-binary-sqlesc"> contains the
characters which must be escaped, and gives the alternate escape
sequences where applicable.
</para>
<table id="datatype-binary-sqlesc">
<title><type>bytea</> Literal Escaped Octets</title>
<tgroup cols="5">
<thead>
<row>
<entry>Decimal Octet Value</entry>
<entry>Description</entry>
<entry>Escaped Input Representation</entry>
<entry>Example</entry>
<entry>Output Representation</entry>
</row>
</thead>
<tbody>
<row>
<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>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>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>
</tgroup>
</table>
<para>
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.
</para>
<para>
The reason that you have to write so many backslashes, as shown in
<xref linkend="datatype-binary-sqlesc">, is that an input string
written as a string literal must pass through two parse phases in
the <productname>PostgreSQL</productname> server. The first
backslash of each pair is interpreted as an escape character by
the string-literal parser and is therefore consumed, leaving the
second backslash of the pair. The remaining backslash is then
recognized by the <type>bytea</type> input function as starting
either a three digit octal value or escaping another backslash.
For example, a string literal passed to the server 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. Note that the apostrophe character is not
treated specially by <type>bytea</type>, so it follows the normal
rules for string literals. (See also <xref
linkend="sql-syntax-strings">.)
</para>
<para>
<type>Bytea</type> octets are also escaped in the output. In general, each
<quote>non-printable</quote> octet is converted into
its equivalent three-digit octal value and preceded by one backslash.
Most <quote>printable</quote> octets are represented by their standard
representation in the client character set. The octet with decimal
value 92 (backslash) has a special alternative output representation.
Details are in <xref linkend="datatype-binary-resesc">.
</para>
<table id="datatype-binary-resesc">
<title><type>bytea</> Output Escaped Octets</title>
<tgroup cols="5">
<thead>
<row>
<entry>Decimal Octet Value</entry>
<entry>Description</entry>
<entry>Escaped Output Representation</entry>
<entry>Example</entry>
<entry>Output Result</entry>
</row>
</thead>
<tbody>
<row>
<entry>92</entry>
<entry>backslash</entry>
<entry><literal>\\</literal></entry>
<entry><literal>SELECT '\\134'::bytea;</literal></entry>
<entry><literal>\\</literal></entry>
</row>
<row>
<entry>0 to 31 and 127 to 255</entry>
<entry><quote>non-printable</quote> octets</entry>
<entry><literal>\<replaceable>xxx</></literal> (octal value)</entry>
<entry><literal>SELECT '\\001'::bytea;</literal></entry>
<entry><literal>\001</literal></entry>
</row>
<row>
<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>
</tgroup>
</table>
<para>
Depending on the front end to <productname>PostgreSQL</> you use,
you may have additional work to do in terms of escaping and
unescaping <type>bytea</type> strings. For example, you may also
have to escape line feeds and carriage returns if your interface
automatically translates these.
</para>
<para>
The <acronym>SQL</acronym> 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">
<title>Date/Time Types</title>
<indexterm zone="datatype-datetime">
<primary>date</primary>
</indexterm>
<indexterm zone="datatype-datetime">
<primary>time</primary>
</indexterm>
<indexterm zone="datatype-datetime">
<primary>time without time zone</primary>
</indexterm>
<indexterm zone="datatype-datetime">
<primary>time with time zone</primary>
</indexterm>
<indexterm zone="datatype-datetime">
<primary>timestamp</primary>
</indexterm>
<indexterm zone="datatype-datetime">
<primary>timestamp with time zone</primary>
</indexterm>
<indexterm zone="datatype-datetime">
<primary>timestamp without time zone</primary>
</indexterm>
<indexterm zone="datatype-datetime">
<primary>interval</primary>
</indexterm>
<indexterm zone="datatype-datetime">
<primary>time span</primary>
</indexterm>
<para>
<productname>PostgreSQL</productname> supports the full set of
<acronym>SQL</acronym> date and time types, shown in <xref
linkend="datatype-datetime-table">.
</para>
<table id="datatype-datetime-table">
<title>Date/Time Types</title>
<tgroup cols="6">
<thead>
<row>
<entry>Name</entry>
<entry>Storage Size</entry>
<entry>Description</entry>
<entry>Low Value</entry>
<entry>High Value</entry>
<entry>Resolution</entry>
</row>
</thead>
<tbody>
<row>
<entry><type>timestamp [ (<replaceable>p</replaceable>) ] [ without time zone ]</type></entry>
<entry>8 bytes</entry>
<entry>both date and time</entry>
<entry>4713 BC</entry>
<entry>AD 5874897</entry>
<entry>1 microsecond / 14 digits</entry>
</row>
<row>
<entry><type>timestamp [ (<replaceable>p</replaceable>) ] with time zone</type></entry>
<entry>8 bytes</entry>
<entry>both date and time, with time zone</entry>
<entry>4713 BC</entry>
<entry>AD 5874897</entry>
<entry>1 microsecond / 14 digits</entry>
</row>
<row>
<entry><type>interval [ (<replaceable>p</replaceable>) ]</type></entry>
<entry>12 bytes</entry>
<entry>time intervals</entry>
<entry>-178000000 years</entry>
<entry>178000000 years</entry>
<entry>1 microsecond</entry>
</row>
<row>
<entry><type>date</type></entry>
<entry>4 bytes</entry>
<entry>dates only</entry>
<entry>4713 BC</entry>
<entry>32767 AD</entry>
<entry>1 day</entry>
</row>
<row>
<entry><type>time [ (<replaceable>p</replaceable>) ] [ without time zone ]</type></entry>
<entry>8 bytes</entry>
<entry>times of day only</entry>
<entry>00:00:00.00</entry>
<entry>23:59:59.99</entry>
<entry>1 microsecond</entry>
</row>
<row>
<entry><type>time [ (<replaceable>p</replaceable>) ] with time zone</type></entry>
<entry>12 bytes</entry>
<entry>times of day only, with time zone</entry>
<entry>00:00:00.00+12</entry>
<entry>23:59:59.99-12</entry>
<entry>1 microsecond</entry>
</row>
</tbody>
</tgroup>
</table>
<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 for the
<type>timestamp</type> and <type>interval</type> types.
</para>
<note>
<para>
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. <type>timestamp</type> values are stored as seconds
since 2000-01-01, and microsecond precision is achieved for dates within
a few years of 2000-01-01, but the precision degrades for dates further
away. When <type>timestamp</type> values are stored as eight-byte integers (a compile-time
option), microsecond precision is available over the full range of
values. However eight-byte integer timestamps have a reduced range of
dates from 4713 BC up to 294276 AD.
</para>
</note>
<note>
<para>
Prior to <productname>PostgreSQL</productname> 7.3, writing just
<type>timestamp</type> was equivalent to <type>timestamp with
time zone</type>. This was changed for SQL compliance.
</para>
</note>
<para>
For the <type>time</type> types, the allowed range of
<replaceable>p</replaceable> is from 0 to 6 when eight-byte integer
storage is used, or from 0 to 10 when floating-point storage is used.
</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.
You are discouraged from using these types in new
applications and are encouraged to move any old
ones over when appropriate. Any or all of these internal types
might disappear in a future release.
</para>
<sect2 id="datatype-datetime-input">
<title>Date/Time Input</title>
<para>
Date and time input is accepted in almost any reasonable format, including
ISO 8601, <acronym>SQL</acronym>-compatible,
traditional <productname>POSTGRES</productname>, and others.
For some formats, ordering of month, day, and year in date input is
ambiguous and there is support for specifying the expected
ordering of these fields. Set the <varname>datestyle</> parameter
to <literal>MDY</> to select month-day-year interpretation,
<literal>DMY</> to select day-month-year interpretation, or
<literal>YMD</> to select year-month-day interpretation.
</para>
<para>
<productname>PostgreSQL</productname> is more flexible in
handling date/time input than the
<acronym>SQL</acronym> standard requires.
See <xref linkend="datetime-appendix">
for the exact parsing rules of date/time input and for the
recognized text fields including months, days of the week, and
time zones.
</para>
<para>
Remember that any date or time literal input needs to be enclosed
in single quotes, like text strings. Refer to
<xref linkend="sql-syntax-constants-generic"> for more
information.
<acronym>SQL</acronym> requires the following syntax
<synopsis>
<replaceable>type</replaceable> [ (<replaceable>p</replaceable>) ] '<replaceable>value</replaceable>'
</synopsis>
where <replaceable>p</replaceable> in the optional precision
specification is an integer corresponding to the number of
fractional digits in the seconds field. Precision can be
specified for <type>time</type>, <type>timestamp</type>, and
<type>interval</type> types. The allowed values are mentioned
above. If no precision is specified in a constant specification,
it defaults to the precision of the literal value.
</para>
<sect3>
<title>Dates</title>
<indexterm>
<primary>date</primary>
</indexterm>
<para>
<xref linkend="datatype-datetime-date-table"> shows some possible
inputs for the <type>date</type> type.
</para>
<table id="datatype-datetime-date-table">
<title>Date Input</title>
<tgroup cols="2">
<thead>
<row>
<entry>Example</entry>
<entry>Description</entry>
</row>
</thead>
<tbody>
<row>
<entry>January 8, 1999</entry>
<entry>unambiguous in any <varname>datestyle</varname> input mode</entry>
</row>
<row>
<entry>1999-01-08</entry>
<entry>ISO 8601; January 8 in any mode
(recommended format)</entry>
</row>
<row>
<entry>1/8/1999</entry>
<entry>January 8 in <literal>MDY</> mode;
August 1 in <literal>DMY</> mode</entry>
</row>
<row>
<entry>1/18/1999</entry>
<entry>January 18 in <literal>MDY</> mode;
rejected in other modes</entry>
</row>
<row>
<entry>01/02/03</entry>
<entry>January 2, 2003 in <literal>MDY</> mode;
February 1, 2003 in <literal>DMY</> mode;
February 3, 2001 in <literal>YMD</> mode
</entry>
</row>
<row>
<entry>1999-Jan-08</entry>
<entry>January 8 in any mode</entry>
</row>
<row>
<entry>Jan-08-1999</entry>
<entry>January 8 in any mode</entry>
</row>
<row>
<entry>08-Jan-1999</entry>
<entry>January 8 in any mode</entry>
</row>
<row>
<entry>99-Jan-08</entry>
<entry>January 8 in <literal>YMD</> mode, else error</entry>
</row>
<row>
<entry>08-Jan-99</entry>
<entry>January 8, except error in <literal>YMD</> mode</entry>
</row>
<row>
<entry>Jan-08-99</entry>
<entry>January 8, except error in <literal>YMD</> mode</entry>
</row>
<row>
<entry>19990108</entry>
<entry>ISO 8601; January 8, 1999 in any mode</entry>
</row>
<row>
<entry>990108</entry>
<entry>ISO 8601; January 8, 1999 in any mode</entry>
</row>
<row>
<entry>1999.008</entry>
<entry>year and day of year</entry>
</row>
<row>
<entry>J2451187</entry>
<entry>Julian day</entry>
</row>
<row>
<entry>January 8, 99 BC</entry>
<entry>year 99 before the Common Era</entry>
</row>
</tbody>
</tgroup>
</table>
</sect3>
<sect3>
<title>Times</title>
<indexterm>
<primary>time</primary>
</indexterm>
<indexterm>
<primary>time without time zone</primary>
</indexterm>
<indexterm>
<primary>time with time zone</primary>
</indexterm>
<para>
The time-of-day types are <type>time [
(<replaceable>p</replaceable>) ] without time zone</type> and
<type>time [ (<replaceable>p</replaceable>) ] with time
zone</type>. Writing just <type>time</type> is equivalent to
<type>time without time zone</type>.
</para>
<para>
Valid input for these types consists of a time of day followed
by an optional time zone. (See <xref
linkend="datatype-datetime-time-table">
and <xref linkend="datatype-timezone-table">.) If a time zone is
specified in the input for <type>time without time zone</type>,
it is silently ignored.
</para>
<table id="datatype-datetime-time-table">
<title>Time Input</title>
<tgroup cols="2">
<thead>
<row>
<entry>Example</entry>
<entry>Description</entry>
</row>
</thead>
<tbody>
<row>
<entry><literal>04:05:06.789</literal></entry>
<entry>ISO 8601</entry>
</row>
<row>
<entry><literal>04:05:06</literal></entry>
<entry>ISO 8601</entry>
</row>
<row>
<entry><literal>04:05</literal></entry>
<entry>ISO 8601</entry>
</row>
<row>
<entry><literal>040506</literal></entry>
<entry>ISO 8601</entry>
</row>
<row>
<entry><literal>04:05 AM</literal></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>
</row>
<row>
<entry><literal>04:05:06.789-8</literal></entry>
<entry>ISO 8601</entry>
</row>
<row>
<entry><literal>04:05:06-08:00</literal></entry>
<entry>ISO 8601</entry>
</row>
<row>
<entry><literal>04:05-08:00</literal></entry>
<entry>ISO 8601</entry>
</row>
<row>
<entry><literal>040506-08</literal></entry>
<entry>ISO 8601</entry>
</row>
<row>
<entry><literal>04:05:06 PST</literal></entry>
<entry>time zone specified by name</entry>
</row>
</tbody>
</tgroup>
</table>
<table tocentry="1" id="datatype-timezone-table">
<title>Time Zone Input</title>
<tgroup cols="2">
<thead>
<row>
<entry>Example</entry>
<entry>Description</entry>
</row>
</thead>
<tbody>
<row>
<entry><literal>PST</literal></entry>
<entry>Pacific Standard Time</entry>
</row>
<row>
<entry><literal>-8:00</literal></entry>
<entry>ISO-8601 offset for PST</entry>
</row>
<row>
<entry><literal>-800</literal></entry>
<entry>ISO-8601 offset for PST</entry>
</row>
<row>
<entry><literal>-8</literal></entry>
<entry>ISO-8601 offset for PST</entry>
</row>
<row>
<entry><literal>zulu</literal></entry>
<entry>Military abbreviation for UTC</entry>
</row>
<row>
<entry><literal>z</literal></entry>
<entry>Short form of <literal>zulu</literal></entry>
</row>
</tbody>
</tgroup>
</table>
</sect3>
<sect3>
<title>Time Stamps</title>
<indexterm>
<primary>timestamp</primary>
</indexterm>
<indexterm>
<primary>timestamp with time zone</primary>
</indexterm>
<indexterm>
<primary>timestamp without time zone</primary>
</indexterm>
<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. Thus
<programlisting>
1999-01-08 04:05:06
</programlisting>
and
<programlisting>
1999-01-08 04:05:06 -8:00
</programlisting>
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
</programlisting>
is supported.
</para>
<para>
For <type>timestamp [without time zone]</type>, any explicit time
zone specified in the input is silently ignored. That is, the
resulting date/time value is derived from the explicit date/time
fields in the input value, and is not adjusted for time zone.
</para>
<para>
For <type>timestamp with time zone</type>, the internally stored
value is always in UTC (Universal
Coordinated Time, traditionally known as Greenwich Mean Time,
<acronym>GMT</>). An input value that has an explicit
time zone specified is converted to UTC using the appropriate offset
for that time zone. If no time zone is stated in the input string,
then it is assumed to be in the time zone indicated by the system's
<varname>timezone</> parameter, and is converted to UTC using the
offset for the <varname>timezone</> zone.
</para>
<para>
When a <type>timestamp with time
zone</type> value is output, it is always converted from UTC to the
current <varname>timezone</> zone, and displayed as local time in that
zone. To see the time in another time zone, either change
<varname>timezone</> or use the <literal>AT TIME ZONE</> construct
(see <xref linkend="functions-datetime-zoneconvert">).
</para>
<para>
Conversions between <type>timestamp without time zone</type> and
<type>timestamp with time zone</type> normally assume that the
<type>timestamp without time zone</type> value should be taken or given
as <varname>timezone</> local time. A different zone reference can
be specified for the conversion using <literal>AT TIME ZONE</>.
</para>
</sect3>
<sect3>
<title>Intervals</title>
<indexterm>
<primary>interval</primary>
</indexterm>
<para>
<type>interval</type> values can be written with the following syntax:
<programlisting>
<optional>@</> <replaceable>quantity</> <replaceable>unit</> <optional><replaceable>quantity</> <replaceable>unit</>...</> <optional><replaceable>direction</></optional>
</programlisting>
Where: <replaceable>quantity</> is a number (possibly signed);
<replaceable>unit</> is <literal>second</literal>,
<literal>minute</literal>, <literal>hour</literal>, <literal>day</literal>,
<literal>week</literal>, <literal>month</literal>, <literal>year</literal>,
<literal>decade</literal>, <literal>century</literal>, <literal>millennium</literal>,
or abbreviations or plurals of these units;
<replaceable>direction</> can be <literal>ago</literal> or
empty. The at sign (<literal>@</>) is optional noise. The amounts
of different units are implicitly added up with appropriate
sign accounting.
</para>
<para>
Quantities of days, hours, minutes, and seconds can be specified without
explicit unit markings. For example, <literal>'1 12:59:10'</> is read
the same as <literal>'1 day 12 hours 59 min 10 sec'</>.
</para>
<para>
The optional precision
<replaceable>p</replaceable> should be between 0 and 6, and
defaults to the precision of the input literal.
</para>
</sect3>
<sect3>
<title>Special Values</title>
<indexterm>
<primary>time</primary>
<secondary>constants</secondary>
</indexterm>
<indexterm>
<primary>date</primary>
<secondary>constants</secondary>
</indexterm>
<para>
The following <acronym>SQL</acronym>-compatible functions can be
used as date or time values for the corresponding data type:
<literal>CURRENT_DATE</literal>, <literal>CURRENT_TIME</literal>,
<literal>CURRENT_TIMESTAMP</literal>, <literal>LOCALTIME</literal>,
<literal>LOCALTIMESTAMP</literal>. The latter four accept an
optional precision specification. (See also <xref
linkend="functions-datetime-current">.)
</para>
<para>
<productname>PostgreSQL</productname> also supports several
special date/time input values for convenience, as shown in <xref
linkend="datatype-datetime-special-table">. The values
<literal>infinity</literal> and <literal>-infinity</literal>
are specially represented inside the system and will be displayed
the same way; but the others are simply notational shorthands
that will be converted to ordinary date/time values when read.
All of these values are treated as normal constants and need to be
written in single quotes.
</para>
<table id="datatype-datetime-special-table">
<title>Special Date/Time Inputs</title>
<tgroup cols="2">
<thead>
<row>
<entry>Input String</entry>
<entry>Valid Types</entry>
<entry>Description</entry>
</row>
</thead>
<tbody>
<row>
<entry><literal>epoch</literal></entry>
<entry><type>date</type>, <type>timestamp</type></entry>
<entry>1970-01-01 00:00:00+00 (Unix system time zero)</entry>
</row>
<row>
<entry><literal>infinity</literal></entry>
<entry><type>timestamp</type></entry>
<entry>later than all other time stamps</entry>
</row>
<row>
<entry><literal>-infinity</literal></entry>
<entry><type>timestamp</type></entry>
<entry>earlier than all other time stamps</entry>
</row>
<row>
<entry><literal>now</literal></entry>
<entry><type>date</type>, <type>time</type>, <type>timestamp</type></entry>
<entry>current transaction's start time</entry>
</row>
<row>
<entry><literal>today</literal></entry>
<entry><type>date</type>, <type>timestamp</type></entry>
<entry>midnight today</entry>
</row>
<row>
<entry><literal>tomorrow</literal></entry>
<entry><type>date</type>, <type>timestamp</type></entry>
<entry>midnight tomorrow</entry>
</row>
<row>
<entry><literal>yesterday</literal></entry>
<entry><type>date</type>, <type>timestamp</type></entry>
<entry>midnight yesterday</entry>
</row>
<row>
<entry><literal>allballs</literal></entry>
<entry><type>time</type></entry>
<entry>00:00:00.00 UTC</entry>
</row>
</tbody>
</tgroup>
</table>
</sect3>
</sect2>
<sect2 id="datatype-datetime-output">
<title>Date/Time Output</title>
<indexterm>
<primary>date</primary>
<secondary>output format</secondary>
<seealso>formatting</seealso>
</indexterm>
<indexterm>
<primary>time</primary>
<secondary>output format</secondary>
<seealso>formatting</seealso>
</indexterm>
<para>
The output format of the date/time types can be set to one of the four
styles ISO 8601,
<acronym>SQL</acronym> (Ingres), traditional POSTGRES, and
German, using the command <literal>SET datestyle</literal>. The default
is the <acronym>ISO</acronym> format. (The
<acronym>SQL</acronym> 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 id="datatype-datetime-output-table">
<title>Date/Time Output Styles</title>
<tgroup cols="3">
<thead>
<row>
<entry>Style Specification</entry>
<entry>Description</entry>
<entry>Example</entry>
</row>
</thead>
<tbody>
<row>
<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>12/17/1997 07:37:16.00 PST</entry>
</row>
<row>
<entry>POSTGRES</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>17.12.1997 07:37:16.00 PST</entry>
</row>
</tbody>
</tgroup>
</table>
<para>
In the <acronym>SQL</acronym> and POSTGRES styles, day appears before
month if DMY field ordering has been specified, otherwise month appears
before day.
(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>
<table id="datatype-datetime-output2-table">
<title>Date Order Conventions</title>
<tgroup cols="3">
<thead>
<row>
<entry><varname>datestyle</varname> Setting</entry>
<entry>Input Ordering</entry>
<entry>Example Output</entry>
</row>
</thead>
<tbody>
<row>
<entry><literal>SQL, DMY</></entry>
<entry><replaceable>day</replaceable>/<replaceable>month</replaceable>/<replaceable>year</replaceable></entry>
<entry>17/12/1997 15:37:16.00 CET</entry>
</row>
<row>
<entry><literal>SQL, MDY</></entry>
<entry><replaceable>month</replaceable>/<replaceable>day</replaceable>/<replaceable>year</replaceable></entry>
<entry>12/17/1997 07:37:16.00 PST</entry>
</row>
<row>
<entry><literal>Postgres, DMY</></entry>
<entry><replaceable>day</replaceable>/<replaceable>month</replaceable>/<replaceable>year</replaceable></entry>
<entry>Wed 17 Dec 07:37:16 1997 PST</entry>
</row>
</tbody>
</tgroup>
</table>
<para>
<type>interval</type> output looks like the input format, except
that units like <literal>century</literal> or
<literal>wek</literal> are converted to years and days and that
<literal>ago</literal> is converted to an appropriate sign. In
ISO mode the output looks like
<programlisting>
<optional> <replaceable>quantity</> <replaceable>unit</> <optional> ... </> </> <optional> <replaceable>days</> </> <optional> <replaceable>hours</>:<replaceable>minutes</>:<replaceable>sekunden</> </optional>
</programlisting>
</para>
<para>
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, or 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">
<title>Time Zones</title>
<indexterm zone="datatype-timezones">
<primary>time zone</primary>
</indexterm>
<para>
Time zones, and time-zone conventions, are influenced by
political decisions, not just earth geometry. Time zones around the
world became somewhat standardized during the 1900's,
but continue to be prone to arbitrary changes.
<productname>PostgreSQL</productname> uses your operating
system's underlying features to provide output time-zone
support, and these systems usually contain information for only
the time period 1902 through 2038 (corresponding to the full
range of conventional Unix system time).
<type>timestamp with time zone</type> and <type>time with time
zone</type> will use time zone
information only within that year range, and assume that times
outside that range are in <acronym>UTC</acronym>.
But since time zone support is derived from the underlying operating
system time-zone capabilities, it can handle daylight-saving time
and other special behavior.
</para>
<para>
<productname>PostgreSQL</productname> endeavors to be compatible with
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>
<listitem>
<para>
Although the <type>date</type> type
does not have an associated time zone, the
<type>time</type> type can.
Time zones in the real world can have no meaning unless
associated with a date as well as a time
since the offset may vary through the year with daylight-saving
time boundaries.
</para>
</listitem>
<listitem>
<para>
The default time zone is specified as a constant numeric offset
from <acronym>UTC</>. It is not possible to adapt to daylight-saving
time when doing date/time arithmetic across
<acronym>DST</acronym> boundaries.
</para>
</listitem>
</itemizedlist>
</para>
<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 type <type>time with
time zone</type> (though it is supported by
<productname>PostgreSQL</productname> for legacy applications and
for compatibility with other <acronym>SQL</acronym>
implementations). <productname>PostgreSQL</productname> assumes
your local time zone for any type containing only date or time.
</para>
<para>
All dates and times are stored internally in
<acronym>UTC</acronym>. Times are converted to local time
on the database server before being sent to the client,
hence by default are in the server time zone.
</para>
<para>
There are several ways to select the time zone used by the server:
<itemizedlist>
<listitem>
<para>
The <envar>TZ</envar> environment variable on the server host
is used by the server as the default time zone, if no other is
specified.
</para>
</listitem>
<listitem>
<para>
The <varname>timezone</varname> configuration parameter can be
set in the file <filename>postgresql.conf</>.
</para>
</listitem>
<listitem>
<para>
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>
</itemizedlist>
</para>
<note>
<para>
If an invalid time zone is specified, the time zone becomes
<acronym>UTC</acronym> (on most systems anyway).
</para>
</note>
<para>
Refer to <xref linkend="datetime-appendix"> for a list of
available time zones.
</para>
</sect2>
<sect2 id="datatype-datetime-internals">
<title>Internals</title>
<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 4713 BC
to far into the future, using the assumption that the length of the
year is 365.2425 days.
</para>
<para>
Date conventions before the 19th century make for interesting reading,
but are not consistent enough to warrant coding into a date/time handler.
</para>
</sect2>
</sect1>
<sect1 id="datatype-boolean">
<title>Boolean Type</title>
<indexterm zone="datatype-boolean">
<primary>Boolean</primary>
<secondary>data type</secondary>
</indexterm>
<indexterm zone="datatype-boolean">
<primary>true</primary>
</indexterm>
<indexterm zone="datatype-boolean">
<primary>false</primary>
</indexterm>
<para>
<productname>PostgreSQL</productname> provides the
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 value.
</para>
<para>
Valid literal values for the <quote>true</quote> state are:
<simplelist>
<member><literal>TRUE</literal></member>
<member><literal>'t'</literal></member>
<member><literal>'true'</literal></member>
<member><literal>'y'</literal></member>
<member><literal>'yes'</literal></member>
<member><literal>'1'</literal></member>
</simplelist>
For the <quote>false</quote> state, the following values can be
used:
<simplelist>
<member><literal>FALSE</literal></member>
<member><literal>'f'</literal></member>
<member><literal>'false'</literal></member>
<member><literal>'n'</literal></member>
<member><literal>'no'</literal></member>
<member><literal>'0'</literal></member>
</simplelist>
Using the key words <literal>TRUE</literal> and
<literal>FALSE</literal> is preferred (and
<acronym>SQL</acronym>-compliant).
</para>
<example id="datatype-boolean-example">
<title>Using the <type>boolean</type> type</title>
<programlisting>
CREATE TABLE test1 (a boolean, b text);
INSERT INTO test1 VALUES (TRUE, 'sic est');
INSERT INTO test1 VALUES (FALSE, 'non est');
SELECT * FROM test1;
a | b
---+---------
t | sic est
f | non est
SELECT * FROM test1 WHERE a;
a | b
---+---------
t | sic est
</programlisting>
</example>
<para>
<xref linkend="datatype-boolean-example"> shows that
<type>boolean</type> values are output using the letters
<literal>t</literal> and <literal>f</literal>.
</para>
<tip>
<para>
Values of the <type>boolean</type> type cannot be cast directly
to other types (e.g., <literal>CAST
(<replaceable>boolval</replaceable> AS integer)</literal> does
not work). This can be accomplished using the
<literal>CASE</literal> expression: <literal>CASE WHEN
<replaceable>boolval</replaceable> THEN 'value if true' ELSE
'value if false' END</literal>. See also <xref
linkend="functions-conditional">.
</para>
</tip>
<para>
<type>boolean</type> uses 1 byte of storage.
</para>
</sect1>
<sect1 id="datatype-geometric">
<title>Geometric Types</title>
<para>
Geometric data types represent two-dimensional spatial
objects. <xref linkend="datatype-geo-table"> shows the geometric
types available in <productname>PostgreSQL</productname>. The
most fundamental type, the point, forms the basis for all of the
other types.
</para>
<table id="datatype-geo-table">
<title>Geometric Types</title>
<tgroup cols="4">
<thead>
<row>
<entry>Name</entry>
<entry>Storage Size</entry>
<entry>Representation</entry>
<entry>Description</entry>
</row>
</thead>
<tbody>
<row>
<entry><type>point</type></entry>
<entry>16 bytes</entry>
<entry>Point on the plane</entry>
<entry>(x,y)</entry>
</row>
<row>
<entry><type>line</type></entry>
<entry>32 bytes</entry>
<entry>Infinite line (not fully implemented)</entry>
<entry>((x1,y1),(x2,y2))</entry>
</row>
<row>
<entry><type>lseg</type></entry>
<entry>32 bytes</entry>
<entry>Finite line segment</entry>
<entry>((x1,y1),(x2,y2))</entry>
</row>
<row>
<entry><type>box</type></entry>
<entry>32 bytes</entry>
<entry>Rectangular box</entry>
<entry>((x1,y1),(x2,y2))</entry>
</row>
<row>
<entry><type>path</type></entry>
<entry>16+16n bytes</entry>
<entry>Closed path (similar to polygon)</entry>
<entry>((x1,y1),...)</entry>
</row>
<row>
<entry><type>path</type></entry>
<entry>16+16n bytes</entry>
<entry>Open path</entry>
<entry>[(x1,y1),...]</entry>
</row>
<row>
<entry><type>polygon</type></entry>
<entry>40+16n bytes</entry>
<entry>Polygon (similar to closed path)</entry>
<entry>((x1,y1),...)</entry>
</row>
<row>
<entry><type>circle</type></entry>
<entry>24 bytes</entry>
<entry>Circle</entry>
<entry><(x,y),r> (center and radius)</entry>
</row>
</tbody>
</tgroup>
</table>
<para>
A rich set of functions and operators is available to perform various geometric
operations such as scaling, translation, rotation, and determining
intersections. They are explained in <xref linkend="functions-geometry">.
</para>
<sect2>
<title>Points</title>
<indexterm>
<primary>point</primary>
</indexterm>
<para>
Points are the fundamental two-dimensional building block for geometric types.
Values of type <type>point</type> are specified using the following syntax:
<synopsis>
( <replaceable>x</replaceable> , <replaceable>y</replaceable> )
<replaceable>x</replaceable> , <replaceable>y</replaceable>
</synopsis>
where <replaceable>x</> and <replaceable>y</> are the respective
coordinates as floating-point numbers.
</para>
</sect2>
<sect2>
<title>Line Segments</title>
<indexterm>
<primary>lseg</primary>
</indexterm>
<indexterm>
<primary>line segment</primary>
</indexterm>
<para>
Line segments (<type>lseg</type>) are represented by pairs of points.
Values of type <type>lseg</type> are specified using the following syntax:
<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>
where
<literal>(<replaceable>x1</replaceable>,<replaceable>y1</replaceable>)</literal>
and
<literal>(<replaceable>x2</replaceable>,<replaceable>y2</replaceable>)</literal>
are the end points of the line segment.
</para>
</sect2>
<sect2>
<title>Boxes</title>
<indexterm>
<primary>box (data type)</primary>
</indexterm>
<indexterm>
<primary>rectangle</primary>
</indexterm>
<para>
Boxes are represented by pairs of points that are opposite
corners of the box.
Values of type <type>box</type> is specified using the following syntax:
<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>
where
<literal>(<replaceable>x1</replaceable>,<replaceable>y1</replaceable>)</literal>
and
<literal>(<replaceable>x2</replaceable>,<replaceable>y2</replaceable>)</literal>
are the opposite corners of the box.
</para>
<para>
Boxes are output using the first syntax.
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 corners.
</para>
</sect2>
<sect2>
<title>Paths</title>
<indexterm>
<primary>path (data type)</primary>
</indexterm>
<para>
Paths are represented by connected sets of points. Paths can be
<firstterm>open</firstterm>, where
the first and last points in the set are not connected, and <firstterm>closed</firstterm>,
where the first and last point are connected. The functions
<function>popen(<replaceable>p</>)</function>
and
<function>pclose(<replaceable>p</>)</function>
are supplied to force a path to be open or closed, and the functions
<function>isopen(<replaceable>p</>)</function>
and
<function>isclosed(<replaceable>p</>)</function>
are supplied to test for either type in an expression.
</para>
<para>
Values of type <type>path</type> are specified using the following syntax:
<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>
where the points are the end points of the line segments
comprising the path. Square brackets (<literal>[]</>) indicate
an open path, while parentheses (<literal>()</>) indicate a
closed path.
</para>
<para>
Paths are output using the first syntax.
</para>
</sect2>
<sect2>
<title>Polygons</title>
<indexterm>
<primary>polygon</primary>
</indexterm>
<para>
Polygons are represented by sets of points. Polygons should probably be
considered equivalent to closed paths, but are stored differently
and have their own set of support routines.
</para>
<para>
Values of type <type>polygon</type> are specified using the following syntax:
<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>
where the points are the end points of the line segments
comprising the boundary of the polygon.
</para>
<para>
Polygons are output using the first syntax.
</para>
</sect2>
<sect2>
<title>Circles</title>
<indexterm>
<primary>circle</primary>
</indexterm>
<para>
Circles are represented by a center point and a radius.
Values of type <type>circle</type> are specified using the following syntax:
<synopsis>
&lt; ( <replaceable>x</replaceable> , <replaceable>y</replaceable> ) , <replaceable>r</replaceable> &gt;
( ( <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>
where
<literal>(<replaceable>x</replaceable>,<replaceable>y</replaceable>)</literal>
is the center and <replaceable>r</replaceable> is the radius of the circle.
</para>
<para>
Circles are output using the first syntax.
</para>
</sect2>
</sect1>
<sect1 id="datatype-net-types">
<title>Network Address Types</title>
<indexterm zone="datatype-net-types">
<primary>network</primary>
<secondary>data types</secondary>
</indexterm>
<para>
<productname>PostgreSQL</> offers data types to store IPv4, IPv6, and MAC
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 Types</title>
<tgroup cols="3">
<thead>
<row>
<entry>Name</entry>
<entry>Storage Size</entry>
<entry>Description</entry>
</row>
</thead>
<tbody>
<row>
<entry><type>cidr</type></entry>
<entry>12 or 24 bytes</entry>
<entry>IPv4 or IPv6 networks</entry>
</row>
<row>
<entry><type>inet</type></entry>
<entry>12 or 24 bytes</entry>
<entry>IPv4 and IPv6 hosts and networks</entry>
</row>
<row>
<entry><type>macaddr</type></entry>
<entry>6 bytes</entry>
<entry>MAC addresses</entry>
</row>
</tbody>
</tgroup>
</table>
<para>
When sorting <type>inet</type> or <type>cidr</type> data types,
IPv4 addresses will always sort before IPv6 addresses, including
IPv4 addresses encapsulated or mapped into IPv6 addresses, such as
::10.2.3.4 or ::ffff::10.4.3.2.
</para>
<sect2 id="datatype-inet">
<title><type>inet</type></title>
<indexterm>
<primary>inet (data type)</primary>
</indexterm>
<para>
The <type>inet</type> type holds an IPv4 or IPv6 host address, and
optionally the identity of the subnet it is in, all in one field.
The subnet identity is represented by stating how many bits of
the host address represent the network address (the
<quote>netmask</quote>). If the netmask is 32 and the address is IPv4,
then the value does not indicate a subnet, only a single host.
In IPv6, the address length is 128 bits, so 128 bits will specify a
unique host address. Note that if you
want to accept networks only, you should use the
<type>cidr</type> type rather than <type>inet</type>.
</para>
<para>
The input format for this type is
<replaceable class="parameter">address/y</replaceable>
where
<replaceable class="parameter">address</replaceable>
is an IPv4 or IPv6 address and
<replaceable class="parameter">y</replaceable>
is the number of bits in the netmask. If the
<replaceable class="parameter">/y</replaceable>
part is left off, then the
netmask is 32 for IPv4 and 128 for IPv6, and the value represents
just a single host. On display, the
<replaceable class="parameter">/y</replaceable>
portion is suppressed if the netmask specifies a single host.
</para>
</sect2>
<sect2 id="datatype-cidr">
<title><type>cidr</></title>
<indexterm>
<primary>cidr</primary>
</indexterm>
<para>
The <type>cidr</type> type holds an IPv4 or IPv6 network specification.
Input and output formats follow Classless Internet Domain Routing
conventions.
The format for specifying networks is <replaceable
class="parameter">address/y</> where <replaceable
class="parameter">address</> is the network represented as an
IPv4 or IPv6 address, and <replaceable
class="parameter">y</> is the number of bits in the netmask. If
<replaceable class="parameter">y</> is omitted, it is calculated
using assumptions from the older classful network numbering system, except
that it will be at least large enough to include all of the octets
written in the input. It is an error to specify a network address
that has bits set to the right of the specified netmask.
</para>
<para>
<xref linkend="datatype-net-cidr-table"> shows some examples.
</para>
<table id="datatype-net-cidr-table">
<title><type>cidr</> Type Input Examples</title>
<tgroup cols="3">
<thead>
<row>
<entry><type>cidr</type> Input</entry>
<entry><type>cidr</type> Output</entry>
<entry><literal><function>abbrev</function>(<type>cidr</type>)</literal></entry>
</row>
</thead>
<tbody>
<row>
<entry>192.168.100.128/25</entry>
<entry>192.168.100.128/25</entry>
<entry>192.168.100.128/25</entry>
</row>
<row>
<entry>192.168/24</entry>
<entry>192.168.0.0/24</entry>
<entry>192.168.0/24</entry>
</row>
<row>
<entry>192.168/25</entry>
<entry>192.168.0.0/25</entry>
<entry>192.168.0.0/25</entry>
</row>
<row>
<entry>192.168.1</entry>
<entry>192.168.1.0/24</entry>
<entry>192.168.1/24</entry>
</row>
<row>
<entry>192.168</entry>
<entry>192.168.0.0/24</entry>
<entry>192.168.0/24</entry>
</row>
<row>
<entry>128.1</entry>
<entry>128.1.0.0/16</entry>
<entry>128.1/16</entry>
</row>
<row>
<entry>128</entry>
<entry>128.0.0.0/16</entry>
<entry>128.0/16</entry>
</row>
<row>
<entry>128.1.2</entry>
<entry>128.1.2.0/24</entry>
<entry>128.1.2/24</entry>
</row>
<row>
<entry>10.1.2</entry>
<entry>10.1.2.0/24</entry>
<entry>10.1.2/24</entry>
</row>
<row>
<entry>10.1</entry>
<entry>10.1.0.0/16</entry>
<entry>10.1/16</entry>
</row>
<row>
<entry>10</entry>
<entry>10.0.0.0/8</entry>
<entry>10/8</entry>
</row>
<row>
<entry>10.1.2.3/32</entry>
<entry>10.1.2.3/32</entry>
<entry>10.1.2.3/32</entry>
</row>
<row>
<entry>2001:4f8:3:ba::/64</entry>
<entry>2001:4f8:3:ba::/64</entry>
<entry>2001:4f8:3:ba::/64</entry>
</row>
<row>
<entry>2001:4f8:3:ba:2e0:81ff:fe22:d1f1/128</entry>
<entry>2001:4f8:3:ba:2e0:81ff:fe22:d1f1/128</entry>
<entry>2001:4f8:3:ba:2e0:81ff:fe22:d1f1</entry>
</row>
<row>
<entry>::ffff:1.2.3.0/120</entry>
<entry>::ffff:1.2.3.0/120</entry>
<entry>::ffff:1.2.3/120</entry>
</row>
<row>
<entry>::ffff:1.2.3.0/128</entry>
<entry>::ffff:1.2.3.0/128</entry>
<entry>::ffff:1.2.3.0/128</entry>
</row>
</tbody>
</tgroup>
</table>
</sect2>
<sect2 id="datatype-inet-vs-cidr">
<title><type>inet</type> vs. <type>cidr</type></title>
<para>
The essential difference between <type>inet</type> and <type>cidr</type>
data types is that <type>inet</type> accepts values with nonzero bits to
the right of the netmask, whereas <type>cidr</type> does not.
</para>
<tip>
<para>
If you do not like the output format for <type>inet</type> or
<type>cidr</type> values, try the functions <function>host</>,
<function>text</>, and <function>abbrev</>.
</para>
</tip>
</sect2>
<sect2 id="datatype-macaddr">
<title><type>macaddr</></>
<indexterm>
<primary>macaddr (data type)</primary>
</indexterm>
<indexterm>
<primary>MAC address</primary>
<see>macaddr</see>
</indexterm>
<para>
The <type>macaddr</> type stores MAC addresses, i.e., Ethernet
card hardware addresses (although MAC addresses are used for
other purposes as well). Input is accepted in various customary
formats, including
<simplelist>
<member><literal>'08002b:010203'</></member>
<member><literal>'08002b-010203'</></member>
<member><literal>'0800.2b01.0203'</></member>
<member><literal>'08-00-2b-01-02-03'</></member>
<member><literal>'08:00:2b:01:02:03'</></member>
</simplelist>
which would all specify the same
address. Upper and lower case is accepted for the digits
<literal>a</> through <literal>f</>. Output is always in the
last of the shown forms.
</para>
<para>
The directory <filename class="directory">contrib/mac</filename>
in the <productname>PostgreSQL</productname> source distribution
contains tools that can be used to map MAC addresses to hardware
manufacturer names.
</para>
</sect2>
</sect1>
<sect1 id="datatype-bit">
<title>Bit String Types</title>
<indexterm zone="datatype-bit">
<primary>bit string</primary>
<secondary>data type</secondary>
</indexterm>
<para>
Bit strings are strings of 1's and 0's. They can be used to store
or visualize bit masks. There are two SQL bit types:
<type>bit(<replaceable>n</replaceable>)</type> and <type>bit
varying(<replaceable>n</replaceable>)</type>, where
<replaceable>n</replaceable> is a positive integer.
</para>
<para>
<type>bit</type> type data must match the length
<replaceable>n</replaceable> exactly; it is an error to attempt to
store shorter or longer bit strings. <type>bit varying</type> data is
of variable length up to the maximum length
<replaceable>n</replaceable>; longer strings will be rejected.
Writing <type>bit</type> without a length is equivalent to
<literal>bit(1)</literal>, while <type>bit varying</type> without a length
specification means unlimited length.
</para>
<note>
<para>
If one explicitly casts a bit-string value to
<type>bit(<replaceable>n</>)</type>, it will be truncated or
zero-padded on the right to be exactly <replaceable>n</> bits,
without raising an error. Similarly,
if one explicitly casts a bit-string value to
<type>bit varying(<replaceable>n</>)</type>, it will be truncated
on the right if it is more than <replaceable>n</> bits.
</para>
</note>
<note>
<para>
Prior to <productname>PostgreSQL</> 7.2, <type>bit</type> data
was always silently truncated or zero-padded on the right, with
or without an explicit cast. This was changed to comply with the
<acronym>SQL</acronym> standard.
</para>
</note>
<para>
Refer to <xref
linkend="sql-syntax-bit-strings"> for information about the syntax
of bit string constants. Bit-logical operators and string
manipulation functions are available; see <xref
linkend="functions">.
</para>
<example>
<title>Using the bit string types</title>
<programlisting>
CREATE TABLE test (a BIT(3), b BIT VARYING(5));
INSERT INTO test VALUES (B'101', B'00');
INSERT INTO test VALUES (B'10', B'101');
<computeroutput>
ERROR: bit string length 2 does not match type bit(3)
</computeroutput>
INSERT INTO test VALUES (B'10'::bit(3), B'101');
SELECT * FROM test;
<computeroutput>
a | b
-----+-----
101 | 00
100 | 101
</computeroutput>
</programlisting>
</example>
</sect1>
&array;
<sect1 id="datatype-oid">
<title>Object Identifier Types</title>
<indexterm zone="datatype-oid">
<primary>object identifier</primary>
<secondary>data type</secondary>
</indexterm>
<indexterm zone="datatype-oid">
<primary>oid</primary>
</indexterm>
<indexterm zone="datatype-oid">
<primary>regproc</primary>
</indexterm>
<indexterm zone="datatype-oid">
<primary>regprocedure</primary>
</indexterm>
<indexterm zone="datatype-oid">
<primary>regoper</primary>
</indexterm>
<indexterm zone="datatype-oid">
<primary>regoperator</primary>
</indexterm>
<indexterm zone="datatype-oid">
<primary>regclass</primary>
</indexterm>
<indexterm zone="datatype-oid">
<primary>regtype</primary>
</indexterm>
<indexterm zone="datatype-oid">
<primary>xid</primary>
</indexterm>
<indexterm zone="datatype-oid">
<primary>cid</primary>
</indexterm>
<indexterm zone="datatype-oid">
<primary>tid</primary>
</indexterm>
<para>
Object identifiers (OIDs) are used internally by
<productname>PostgreSQL</productname> as primary keys for various system
tables. Also, an OID system column is added to user-created tables
(unless <literal>WITHOUT OIDS</> is specified at table creation time).
Type <type>oid</> represents an object identifier. There are also
several alias types for <type>oid</>: <type>regproc</>, <type>regprocedure</>,
<type>regoper</>, <type>regoperator</>, <type>regclass</>,
and <type>regtype</>. <xref linkend="datatype-oid-table"> shows an overview.
</para>
<para>
The <type>oid</> type is currently implemented as an unsigned four-byte
integer.
Therefore, it is not large enough to provide database-wide uniqueness
in large databases, or even in large individual tables. So, using a
user-created table's OID column as a primary key is discouraged.
OIDs are best used only for references to system tables.
</para>
<para>
The <type>oid</> type itself has few operations beyond comparison.
It can be cast to
integer, however, and then manipulated using the standard integer
operators. (Beware of possible signed-versus-unsigned confusion
if you do this.)
</para>
<para>
The OID alias types have no operations of their own except
for specialized input and output routines. These routines are able
to accept and display symbolic names for system objects, rather than
the raw numeric value that type <type>oid</> would use. The alias
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 <command>SELECT</> would
be needed to deal with selecting the right OID when there are multiple
tables named <literal>mytable</> in different schemas.)
</para>
<table id="datatype-oid-table">
<title>Object Identifier Types</title>
<tgroup cols="4">
<thead>
<row>
<entry>Name</entry>
<entry>References</entry>
<entry>Description</entry>
<entry>Value Example</entry>
</row>
</thead>
<tbody>
<row>
<entry><type>oid</></entry>
<entry>any</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><literal>sum</></entry>
</row>
<row>
<entry><type>regprocedure</></entry>
<entry><structname>pg_proc</></entry>
<entry>function with argument types</entry>
<entry><literal>sum(int4)</></entry>
</row>
<row>
<entry><type>regoper</></entry>
<entry><structname>pg_operator</></entry>
<entry>operator name</entry>
<entry><literal>+</></entry>
</row>
<row>
<entry><type>regoperator</></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><structname>pg_class</></entry>
<entry>relation name</entry>
<entry><literal>pg_type</></entry>
</row>
<row>
<entry><type>regtype</></entry>
<entry><structname>pg_type</></entry>
<entry>data type name</entry>
<entry><literal>integer</></entry>
</row>
</tbody>
</tgroup>
</table>
<para>
All of the OID alias types accept schema-qualified names, and will
display schema-qualified names on output if the object would not
be found in the current search path without being qualified.
The <type>regproc</> and <type>regoper</> alias types will only
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 <literal>NONE</> for the unused
operand.
</para>
<para>
Another identifier type used by the system is <type>xid</>, or transaction
(abbreviated <abbrev>xact</>) identifier. This is the data type of the system columns
<structfield>xmin</> and <structfield>xmax</>. Transaction identifiers are 32-bit quantities.
</para>
<para>
A third identifier type used by the system is <type>cid</>, or
command identifier. This is the data type of the system columns
<structfield>cmin</> and <structfield>cmax</>. Command identifiers are also 32-bit quantities.
</para>
<para>
A final identifier type used by the system is <type>tid</>, or tuple
identifier (row identifier). This is the data type of the system column
<structfield>ctid</>. A tuple ID is a pair
(block number, tuple index within block) that identifies the
physical location of the row within its table.
</para>
<para>
(The system columns are further explained in <xref
linkend="ddl-system-columns">.)
</para>
</sect1>
<sect1 id="datatype-pseudo">
<title>Pseudo-Types</title>
<indexterm zone="datatype-pseudo">
<primary>record</primary>
</indexterm>
<indexterm zone="datatype-pseudo">
<primary>any</primary>
</indexterm>
<indexterm zone="datatype-pseudo">
<primary>anyarray</primary>
</indexterm>
<indexterm zone="datatype-pseudo">
<primary>anyelement</primary>
</indexterm>
<indexterm zone="datatype-pseudo">
<primary>void</primary>
</indexterm>
<indexterm zone="datatype-pseudo">
<primary>trigger</primary>
</indexterm>
<indexterm zone="datatype-pseudo">
<primary>language_handler</primary>
</indexterm>
<indexterm zone="datatype-pseudo">
<primary>cstring</primary>
</indexterm>
<indexterm zone="datatype-pseudo">
<primary>internal</primary>
</indexterm>
<indexterm zone="datatype-pseudo">
<primary>opaque</primary>
</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
<acronym>SQL</acronym> data type. <xref
linkend="datatype-pseudotypes-table"> lists the existing
pseudo-types.
</para>
<table id="datatype-pseudotypes-table">
<title>Pseudo-Types</title>
<tgroup cols="2">
<thead>
<row>
<entry>Name</entry>
<entry>Description</entry>
</row>
</thead>
<tbody>
<row>
<entry><type>any</></entry>
<entry>Indicates that a function accepts any input data type whatever.</entry>
</row>
<row>
<entry><type>anyarray</></entry>
<entry>Indicates that a function accepts any array data type
(see <xref linkend="extend-types-polymorphic">).</entry>
</row>
<row>
<entry><type>anyelement</></entry>
<entry>Indicates that a function accepts any data type
(see <xref linkend="extend-types-polymorphic">).</entry>
</row>
<row>
<entry><type>cstring</></entry>
<entry>Indicates that a function accepts or returns a null-terminated C string.</entry>
</row>
<row>
<entry><type>internal</></entry>
<entry>Indicates that a function accepts or returns a server-internal
data type.</entry>
</row>
<row>
<entry><type>language_handler</></entry>
<entry>A procedural language call handler is declared to return <type>language_handler</>.</entry>
</row>
<row>
<entry><type>record</></entry>
<entry>Identifies a function returning an unspecified row type.</entry>
</row>
<row>
<entry><type>trigger</></entry>
<entry>A trigger function is declared to return <type>trigger.</></entry>
</row>
<row>
<entry><type>void</></entry>
<entry>Indicates that a function returns no value.</entry>
</row>
<row>
<entry><type>opaque</></entry>
<entry>An obsolete type name that formerly served all the above purposes.</entry>
</row>
</tbody>
</tgroup>
</table>
<para>
Functions coded in C (whether built-in or dynamically loaded) may be
declared to accept or return any of these pseudo data types. It is up to
the function author to ensure that the function will behave safely
when a pseudo-type is used as an argument type.
</para>
<para>
Functions coded in procedural languages may use pseudo-types only as
allowed by their implementation languages. At present the procedural
languages all forbid use of a pseudo-type as argument type, and allow
only <type>void</> and <type>record</> as a result type (plus
<type>trigger</> when the function is used as a trigger). Some also
support polymorphic functions using the types <type>anyarray</> and
<type>anyelement</>.
</para>
<para>
The <type>internal</> pseudo-type is used to declare functions
that are meant only to be called internally by the database
system, and not by direct invocation in a <acronym>SQL</acronym>
query. If a function has at least one <type>internal</>-type
argument then it cannot be called from <acronym>SQL</acronym>. To
preserve the type safety of this restriction it is important to
follow this coding rule: do not create any function that is
declared to return <type>internal</> unless it has at least one
<type>internal</> argument.
</para>
</sect1>
</chapter>
<!-- Keep this comment at the end of the file
Local variables:
mode:sgml
sgml-omittag:nil
sgml-shorttag:t
sgml-minimize-attributes:nil
sgml-always-quote-attributes:t
sgml-indent-step:1
sgml-indent-tabs-mode:nil
sgml-indent-data:t
sgml-parent-document:nil
sgml-default-dtd-file:"./reference.ced"
sgml-exposed-tags:nil
sgml-local-catalogs:("/usr/share/sgml/catalog")
sgml-local-ecat-files:nil
End:
-->