postgresql/doc/src/sgml/datatype.sgml

2930 lines
88 KiB
Plaintext
Raw Normal View History

<!--
$Header: /cvsroot/pgsql/doc/src/sgml/datatype.sgml,v 1.82 2002/01/04 17:02:02 thomas Exp $
-->
<chapter id="datatype">
1999-06-14 09:36:12 +02:00
<title id="datatype-title">Data Types</title>
1998-03-01 09:16:16 +01:00
<indexterm zone="datatype">
<primary>data types</primary>
</indexterm>
<indexterm>
<primary>types</primary>
<see>data types</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
2000-04-13 23:44:25 +02:00
<command>CREATE TYPE</command> command.
</para>
1998-03-01 09:16:16 +01:00
<para>
<xref linkend="datatype-table"> shows all general-purpose data types
2001-11-19 10:05:02 +01:00
included in the standard distribution. 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,
2001-11-19 10:05:02 +01:00
but they are not listed here.
</para>
<para>
<table id="datatype-table">
<title>Data Types</title>
<tgroup cols="3">
<thead>
<row>
<entry>Type 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 2D plane</entry>
</row>
<row>
<entry><type>bytea</type></entry>
<entry></entry>
<entry>binary data</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>
1999-10-13 04:44:23 +02:00
<row>
<entry><type>character varying(<replaceable>n</replaceable>)</type></entry>
<entry><type>varchar(<replaceable>n</replaceable>)</type></entry>
<entry>variable-length character string</entry>
1999-10-13 04:44:23 +02:00
</row>
<row>
<entry><type>cidr</type></entry>
<entry></entry>
<entry>IP network address</entry>
</row>
<row>
<entry><type>circle</type></entry>
<entry></entry>
<entry>circle in 2D 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>IP 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>
2000-03-14 23:52:53 +01:00
<row>
<entry><type>interval(<replaceable>p</replaceable>)</type></entry>
<entry></entry>
2000-03-14 23:52:53 +01:00
<entry>general-use time span</entry>
</row>
<row>
<entry><type>line</type></entry>
<entry></entry>
<entry>infinite line in 2D plane</entry>
</row>
<row>
<entry><type>lseg</type></entry>
<entry></entry>
<entry>line segment in 2D plane</entry>
</row>
<row>
<entry><type>macaddr</type></entry>
<entry></entry>
<entry>MAC address</entry>
</row>
1999-10-13 04:44:23 +02:00
<row>
<entry><type>money</type></entry>
<entry></entry>
<entry>US-style currency</entry>
1999-10-13 04:44:23 +02:00
</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>oid</type></entry>
<entry></entry>
<entry>object identifier</entry>
</row>
<row>
<entry><type>path</type></entry>
<entry></entry>
<entry>open and closed geometric path in 2D plane</entry>
</row>
<row>
<entry><type>point</type></entry>
<entry></entry>
<entry>geometric point in 2D plane</entry>
</row>
<row>
<entry><type>polygon</type></entry>
<entry></entry>
<entry>closed geometric path in 2D 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>
2001-11-28 21:49:10 +01:00
<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>
2001-11-28 21:49:10 +01:00
<entry><type>timestamp</type></entry>
<entry>date and time</entry>
</row>
<row>
<entry><type>timestamp [ (<replaceable>p</replaceable>) ] [ with time zone ]</type></entry>
2001-11-28 21:49:10 +01:00
<entry><type>timestamptz</type></entry>
2001-11-19 10:05:02 +01:00
<entry>date and time, including time zone</entry>
</row>
</tbody>
</tgroup>
</table>
</para>
1998-10-27 07:14:41 +01:00
<note>
<title>Compatibility</title>
<para>
The following types (or spellings thereof) are specified by SQL:
<type>bit</type>, <type>bit varying</type>, <type>boolean</type>,
<type>char</type>, <type>character</type>, <type>character
varying</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>,
<type>timestamp</type> (both with or without time zone).
</para>
</note>
1998-03-01 09:16:16 +01:00
<para>
2001-11-19 10:05:02 +01:00
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
2001-11-19 10:05:02 +01:00
paths, or have several possibilities for formats, such as the date
and time types.
Most of the input and output functions corresponding to the
base types (e.g., integers and floating point numbers) do some
error-checking.
2001-11-19 10:05:02 +01:00
Some of the input and output functions are not invertible. That is,
the result of an output function may lose precision 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 underflow or overflow.
</para>
1998-03-01 09:16:16 +01:00
<sect1 id="datatype-numeric">
<title>Numeric Types</title>
1998-03-01 09:16:16 +01:00
<indexterm zone="datatype-numeric">
<primary>data types</primary>
<secondary>numeric</secondary>
</indexterm>
<indexterm zone="datatype-numeric">
<primary>integer</primary>
</indexterm>
<indexterm zone="datatype-numeric">
<primary>smallint</primary>
</indexterm>
<indexterm zone="datatype-numeric">
<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>
<indexterm zone="datatype-numeric">
<primary>numeric (data type)</primary>
</indexterm>
<indexterm>
<primary>decimal</primary>
<see>numeric</see>
</indexterm>
<indexterm zone="datatype-numeric">
<primary>real</primary>
</indexterm>
<indexterm zone="datatype-numeric">
<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-numeric">
<primary>floating point</primary>
</indexterm>
<para>
Numeric types consist of two-, four-, and eight-byte integers,
four- and eight-byte
floating point numbers and fixed-precision decimals.
</para>
<para>
<table tocentry="1">
<title>Numeric Types</title>
<tgroup cols="4">
<thead>
<row>
<entry>Type name</entry>
<entry>Storage size</entry>
<entry>Description</entry>
<entry>Range</entry>
</row>
</thead>
<tbody>
1999-10-13 04:44:23 +02:00
<row>
<entry><type>smallint</></entry>
<entry>2 bytes</entry>
<entry>Fixed-precision</entry>
<entry>-32768 to +32767</entry>
</row>
<row>
<entry><type>integer</></entry>
<entry>4 bytes</entry>
<entry>Usual choice for fixed-precision</entry>
<entry>-2147483648 to +2147483647</entry>
</row>
<row>
<entry><type>bigint</></entry>
<entry>8 bytes</entry>
<entry>Very large range fixed-precision</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>
1999-10-13 04:44:23 +02:00
</row>
<row>
<entry><type>numeric</></entry>
1999-10-13 04:44:23 +02:00
<entry>variable</entry>
<entry>user-specified precision, exact</entry>
1999-10-13 04:44:23 +02:00
<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>autoincrementing integer</entry>
<entry>1 to 9223372036854775807</entry>
</row>
</tbody>
</tgroup>
</table>
</para>
<para>
The syntax of constants for the numeric types is described in
<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>The Integer Types</title>
<para>
The types <type>smallint</type>, <type>integer</type>,
<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>
2001-11-19 10:05:02 +01:00
<para>
SQL 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 RDBMS products.
</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
2001-11-19 10:05:02 +01:00
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>
2001-11-19 10:05:02 +01:00
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>
<para>
The type <type>numeric</type> can store numbers of practically
unlimited size and precision, while being able to store all
numbers and carry out all 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.
2001-11-28 21:49:10 +01:00
(The SQL standard requires a default scale of 0, i.e., coercion to
integer accuracy. We find this a bit useless. If you're concerned about
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 SQL standard.
</para>
</sect2>
<sect2 id="datatype-float">
<title>Floating Point Types</title>
<para>
The data types <type>real</type> and <type>double
precision</type> are inexact, variable precision numeric types.
In practice, these types are usually implementations of <acronym>IEEE</acronym> 754
binary floating point (single and double precision,
respectively), to the extent that the underlying processor,
operating system, and compiler support it.
</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>
Normally, the <type>real</type> type has a range of at least
2001-11-19 10:05:02 +01:00
-1E+37 to +1E+37 with a precision of at least 6 decimal digits. The
<type>double precision</type> type normally has a range of around
2001-11-19 10:05:02 +01:00
-1E+308 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>
</sect2>
<sect2 id="datatype-serial">
<title>The Serial Types</title>
<indexterm zone="datatype-serial">
<primary>serial</primary>
</indexterm>
2001-10-30 21:13:44 +01:00
<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>sequences</primary>
<secondary>and serial type</secondary>
</indexterm>
<para>
The <type>serial</type> data types are not truly types, but are a
notational convenience for setting up unique identifier columns
in tables.
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') UNIQUE NOT NULL
);
</programlisting>
Thus, we have created an integer column and arranged for its default
values to be assigned from a sequence generator. UNIQUE and NOT NULL
constraints are applied to ensure that explicitly-inserted values
will never be duplicates, either.
</para>
<important>
<para>
The implicit sequence created for the <type>serial</type> type will
<emphasis>not</emphasis> be automatically removed when the
table is dropped.
</para>
</important>
<para>
The type names <type>serial</type> and <type>serial4</type> are
equivalent: both create <type>integer</type> columns. The type
2001-10-30 21:13:44 +01:00
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
2001-11-28 21:49:10 +01:00
use of more than 2<superscript>31</> identifiers over the lifetime of the table.
</para>
<para>
2001-10-30 21:13:44 +01:00
Implicit sequences supporting the <type>serial</type> types are
not automatically dropped when a table containing a serial type
is dropped. So, the following commands executed in order will likely fail:
<programlisting>
CREATE TABLE <replaceable class="parameter">tablename</replaceable> (<replaceable class="parameter">colname</replaceable> SERIAL);
DROP TABLE <replaceable class="parameter">tablename</replaceable>;
CREATE TABLE <replaceable class="parameter">tablename</replaceable> (<replaceable class="parameter">colname</replaceable> SERIAL);
</programlisting>
The sequence will remain in the database until explicitly dropped using
2001-10-30 21:13:44 +01:00
<command>DROP SEQUENCE</command>. (This annoyance will probably be
changed in some future release.)
</para>
</sect2>
</sect1>
<sect1 id="datatype-money">
<title>Monetary Type</title>
<note>
<title>Deprecated</title>
<para>
2001-03-25 00:03:26 +01:00
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. The
money type may become a locale-aware layer over the
<type>numeric</type> type in a future release.
</para>
</note>
<para>
The <type>money</type> type stores U.S.-style currency with fixed
decimal point representation. If
<productname>PostgreSQL</productname> is compiled with locale
support then the <type>money</type> type uses locale-specific
output formatting.
</para>
<para>
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 in the latter form.
</para>
<para>
<table tocentry="1">
<title>Monetary Types</title>
<tgroup cols="4">
<thead>
<row>
<entry>Type Name</entry>
<entry>Storage</entry>
<entry>Description</entry>
<entry>Range</entry>
</row>
</thead>
<tbody>
<row>
<entry>money</entry>
<entry>4 bytes</entry>
<entry>Fixed-precision</entry>
<entry>-21474836.48 to +21474836.47</entry>
</row>
</tbody>
</tgroup>
</table>
</para>
</sect1>
1998-03-01 09:16:16 +01:00
<sect1 id="datatype-character">
<title>Character Types</title>
<indexterm zone="datatype-character">
<primary>character strings</primary>
<secondary>data types</secondary>
</indexterm>
<indexterm>
<primary>strings</primary>
<see>character strings</see>
</indexterm>
<indexterm>
<primary>text</primary>
<see>character strings</see>
</indexterm>
<table tocentry="1">
<title>Character Types</title>
<tgroup cols="2">
<thead>
<row>
<entry>Type name</entry>
<entry>Description</entry>
</row>
</thead>
<tbody>
<row>
<entry><type>character(<replaceable>n</>)</type>, <type>char(<replaceable>n</>)</type></entry>
<entry>Fixed-length blank padded</entry>
</row>
<row>
<entry><type>character varying(<replaceable>n</>)</type>, <type>varchar(<replaceable>n</>)</type></entry>
<entry>Variable-length with limit</entry>
</row>
<row>
<entry><type>text</type></entry>
<entry>Variable unlimited length</entry>
</row>
</tbody>
</tgroup>
</table>
<para>
<acronym>SQL</acronym> defines two primary character types:
<type>character(<replaceable>n</>)</type> and <type>character
varying(<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 SQL 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>
<note>
<para>
Prior to <productname>PostgreSQL</> 7.2, strings that were too long were silently
truncated, no error was raised.
</para>
</note>
<para>
The notations <type>char(<replaceable>n</>)</type> and
<type>varchar(<replaceable>n</>)</type> are aliases for
<type>character(<replaceable>n</>)</type> and <type>character
varying(<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> supports the
more general <type>text</type> type, which stores strings of any
length. Unlike <type>character varying</type>, <type>text</type>
does not require an explicit declared upper limit on the size of
the string. Although the type <type>text</type> is not in the SQL
standard, many other RDBMS packages 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 will be compressed by the system
2001-11-28 21:49:10 +01:00
automatically, so the physical requirement on disk may be less.
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>
SELECT b, char_length(b) FROM test2;
<computeroutput>
b | char_length
-------+-------------
ok | 2
good | 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>. The <type>name</type> type
exists <emphasis>only</emphasis> for storage of internal catalog
names and is not intended for use by the general user. Its length
is currently defined as 32 bytes (31 usable characters plus terminator)
but should be referenced using the macro
<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>
1998-03-01 09:16:16 +01:00
<table tocentry="1">
<title>Specialty Character Type</title>
<tgroup cols="3">
<thead>
<row>
<entry>Type Name</entry>
<entry>Storage</entry>
<entry>Description</entry>
</row>
</thead>
<tbody>
<row>
<entry>"char"</entry>
<entry>1 byte</entry>
<entry>Single character internal type</entry>
</row>
<row>
<entry>name</entry>
<entry>32 bytes</entry>
2000-03-14 23:52:53 +01:00
<entry>Thirty-one character internal type</entry>
</row>
</tbody>
</tgroup>
</table>
</sect1>
<sect1 id="datatype-binary">
<title>Binary Strings</title>
<para>
The <type>bytea</type> data type allows storage of binary strings.
</para>
<table tocentry="1">
<title>Binary String Types</title>
<tgroup cols="3">
<thead>
<row>
<entry>Type Name</entry>
<entry>Storage</entry>
<entry>Description</entry>
</row>
</thead>
<tbody>
<row>
<entry>bytea</entry>
<entry>4 bytes plus the actual binary string</entry>
<entry>Variable (not specifically limited)
length binary string</entry>
</row>
</tbody>
</tgroup>
</table>
<para>
A binary string is a sequence of octets that does not have either a
character set or collation associated with it. <type>Bytea</type>
specifically allows storing octets of zero value and other
<quote>non-printable</quote> octets.
</para>
<para>
Octets of certain values <emphasis>must</emphasis> be escaped (but all
octet values <emphasis>may</emphasis> be escaped) when used as part of
a string literal in an <acronym>SQL</acronym> statement. In general,
2001-11-28 21:49:10 +01:00
to escape an octet, it is converted into the three-digit octal number
2001-11-21 22:12:34 +01:00
equivalent of its decimal octet value, and preceded by two
backslashes. Some octet values have alternate escape sequences, as
shown in <xref linkend="datatype-binary-sqlesc">.
</para>
<table id="datatype-binary-sqlesc">
<title><acronym>SQL</acronym> Literal Escaped Octets</title>
<tgroup cols="5">
<thead>
<row>
<entry>Decimal Octet Value</entry>
<entry>Description</entry>
<entry>Input Escaped Representation</entry>
<entry>Example</entry>
<entry>Printed Result</entry>
</row>
</thead>
<tbody>
<row>
<entry> <literal> 0 </literal> </entry>
<entry> zero octet </entry>
<entry> <literal> '\\000' </literal> </entry>
<entry> <literal> select '\\000'::bytea; </literal> </entry>
<entry> <literal> \000 </literal></entry>
</row>
<row>
<entry> <literal> 39 </literal> </entry>
<entry> single quote </entry>
<entry> <literal> '\\'' or '\\047' </literal> </entry>
<entry> <literal> select '\''::bytea; </literal></entry>
<entry> <literal> ' </literal></entry>
</row>
<row>
<entry> <literal>92</literal> </entry>
<entry> backslash </entry>
<entry> <literal> '\\\\' or '\\134' </literal> </entry>
<entry> <literal> select '\\\\'::bytea; </literal></entry>
<entry> <literal> \\ </literal></entry>
</row>
</tbody>
</tgroup>
</table>
<para>
Note that the result in each of the examples above was exactly one
octet in length, even though the output representation of the zero
octet and backslash are more than one character. <type>Bytea</type>
output octets are also escaped. In general, each
<quote>non-printable</quote> octet decimal value is converted into
2001-11-21 22:12:34 +01:00
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 alternate output representation.
Details are in <xref linkend="datatype-binary-resesc">.
</para>
<table id="datatype-binary-resesc">
<title><acronym>SQL</acronym> Output Escaped Octets</title>
<tgroup cols="5">
<thead>
<row>
<entry>Decimal Octet Value</entry>
<entry>Description</entry>
<entry>Output Escaped Representation</entry>
<entry>Example</entry>
<entry>Printed Result</entry>
</row>
</thead>
<tbody>
<row>
<entry> <literal> 92 </literal> </entry>
<entry> backslash </entry>
<entry> <literal> \\ </literal> </entry>
<entry> <literal> select '\\134'::bytea; </literal></entry>
<entry> <literal> \\ </literal></entry>
</row>
<row>
<entry> <literal> 0 to 31 and 127 to 255 </literal> </entry>
<entry> <quote>non-printable</quote> octets </entry>
<entry> <literal> \### (octal value) </literal> </entry>
<entry> <literal> select '\\001'::bytea; </literal> </entry>
<entry> <literal> \001 </literal></entry>
</row>
<row>
<entry> <literal> 32 to 126 </literal> </entry>
<entry> <quote>printable</quote> octets </entry>
2001-11-21 22:12:34 +01:00
<entry> ASCII representation </entry>
<entry> <literal> select '\\176'::bytea; </literal> </entry>
<entry> <literal> ~ </literal></entry>
</row>
</tbody>
</tgroup>
</table>
<para>
<acronym>SQL</acronym> string literals (input strings) must be
2001-11-21 22:12:34 +01:00
preceded with two backslashes due to the fact that they must pass
through two parsers in the PostgreSQL backend. The first backslash
2001-11-28 21:49:10 +01:00
is interpreted as an escape character by the string-literal parser,
and therefore is consumed, leaving the octets that follow.
2001-11-21 22:12:34 +01:00
The remaining backslash is recognized by the <type>bytea</type> input
function as the prefix of a three digit octal value. For example, a string
literal passed to the backend as <literal>'\\001'</literal> becomes
2001-11-28 21:49:10 +01:00
<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.
</para>
<para>
For a similar reason, a backslash must be input as
<literal>'\\\\'</literal> (or <literal>'\\134'</literal>). The first
2001-11-21 22:12:34 +01:00
and third backslashes are interpreted as escape characters by the
2001-11-28 21:49:10 +01:00
string-literal parser, and therefore are consumed, leaving two
2001-11-21 22:12:34 +01:00
backslashes in the string passed to the <type>bytea</type> input function,
which interprets them as representing a single backslash.
For example, a string literal passed to the
backend as <literal>'\\\\'</literal> becomes <literal>'\\'</literal>
2001-11-28 21:49:10 +01:00
after passing through the string-literal parser. The
<literal>'\\'</literal> is then sent to the <type>bytea</type> input
function, where it is converted to a single octet with a decimal
value of 92.
</para>
<para>
A single quote is a bit different in that it must be input as
<literal>'\''</literal> (or <literal>'\\134'</literal>),
<emphasis>not</emphasis> as <literal>'\\''</literal>. This is because,
while the literal parser interprets the single quote as a special
character, and will consume the single backslash, the
<type>bytea</type> input function does <emphasis>not</emphasis>
recognize a single quote as a special octet. Therefore a string
literal passed to the backend as <literal>'\''</literal> becomes
2001-11-28 21:49:10 +01:00
<literal>'''</literal> after passing through the string-literal
parser. The <literal>'''</literal> is then sent to the
<type>bytea</type> input function, where it is retains its single
octet decimal value of 39.
</para>
<para>
Depending on the front end to 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. Or you may have to double up on backslashes if
the parser for your language or choice also treats them as an
2001-11-21 22:12:34 +01:00
escape character.
</para>
<sect2 id="datatype-binary-compat">
<title>Compatibility</title>
<para>
<type>Bytea</type> provides most of the functionality of the binary
string type per SQL99 section 4.3. A comparison of SQL99 Binary
Strings and PostgreSQL <type>bytea</type> is presented in
<xref linkend="datatype-binary-compat-comp">.
</para>
<table id="datatype-binary-compat-comp">
<title>Comparison of SQL99 Binary String and PostgreSQL
<type>BYTEA</type> types</title>
<tgroup cols="2">
<thead>
<row>
<entry>SQL99</entry>
<entry><type>BYTEA</type></entry>
</row>
</thead>
<tbody>
<row>
<entry> Name of data type <type>BINARY LARGE OBJECT</type>
or <type>BLOB</type> </entry>
<entry> Name of data type <type>BYTEA</type> </entry>
</row>
<row>
<entry> Sequence of octets that does not have either a character set
or collation associated with it. </entry>
<entry> same </entry>
</row>
<row>
<entry> Described by a binary data type descriptor containing the
name of the data type and the maximum length
in octets</entry>
<entry> Described by a binary data type descriptor containing the
name of the data type with no specific maximum length
</entry>
</row>
<row>
<entry> All binary strings are mutually comparable in accordance
with the rules of comparison predicates.</entry>
<entry> same</entry>
</row>
<row>
<entry> Binary string values can only be compared for equality.
</entry>
<entry> Binary string values can be compared for equality, greater
than, greater than or equal, less than, less than or equal
</entry>
</row>
<row>
<entry> Operators operating on and returning binary strings
include concatenation, substring, overlay, and trim</entry>
<entry> Operators operating on and returning binary strings
2001-11-28 21:49:10 +01:00
include concatenation, substring, and trim. The
<literal>leading</literal> and <literal>trailing</literal>
arguments for trim are not yet implemented.
</entry>
</row>
<row>
<entry> Other operators involving binary strings
include length, position, and the like predicate</entry>
<entry> same</entry>
</row>
<row>
<entry> A binary string literal is comprised of an even number of
2001-11-21 22:12:34 +01:00
hexadecimal digits, in single quotes, preceded by <quote>X</quote>,
e.g. <literal>X'1a43fe'</literal></entry>
<entry> A binary string literal is comprised of octets
escaped according to the rules shown in
<xref linkend="datatype-binary-sqlesc"> </entry>
</row>
</tbody>
</tgroup>
</table>
</sect2>
</sect1>
<sect1 id="datatype-datetime">
<title>Date/Time Types</title>
<para>
<productname>PostgreSQL</productname> supports the full set of
<acronym>SQL</acronym> date and time types.
</para>
1998-10-27 07:14:41 +01:00
<para>
<table tocentry="1">
<title>Date/Time Types</title>
<tgroup cols="6">
<thead>
<row>
<entry>Type</entry>
<entry>Description</entry>
<entry>Storage</entry>
<entry>Earliest</entry>
<entry>Latest</entry>
<entry>Resolution</entry>
</row>
</thead>
<tbody>
<row>
<entry><type>timestamp [ (<replaceable>p</replaceable>) ] without time zone</type></entry>
<entry>both date and time</entry>
<entry>8 bytes</entry>
<entry>4713 BC</entry>
<entry>AD 1465001</entry>
<entry>1 microsecond / 14 digits</entry>
</row>
2000-03-14 23:52:53 +01:00
<row>
<entry><type>timestamp [ (<replaceable>p</replaceable>) ] [ with time zone ]</type></entry>
<entry>both date and time</entry>
2000-03-14 23:52:53 +01:00
<entry>8 bytes</entry>
<entry>4713 BC</entry>
<entry>AD 1465001</entry>
<entry>1 microsecond / 14 digits</entry>
2000-03-14 23:52:53 +01:00
</row>
<row>
2001-12-23 21:21:37 +01:00
<entry><type>interval [ (<replaceable>p</replaceable>) ]</type></entry>
<entry>for time intervals</entry>
<entry>12 bytes</entry>
<entry>-178000000 years</entry>
<entry>178000000 years</entry>
<entry>1 microsecond</entry>
</row>
<row>
<entry><type>date</type></entry>
<entry>dates only</entry>
<entry>4 bytes</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>times of day only</entry>
<entry>8 bytes</entry>
<entry>00:00:00.00</entry>
<entry>23:59:59.99</entry>
<entry>1 microsecond</entry>
</row>
2000-03-14 23:52:53 +01:00
<row>
<entry><type>time [ (<replaceable>p</replaceable>) ] with time zone</type></entry>
<entry>times of day only</entry>
<entry>12 bytes</entry>
2000-03-14 23:52:53 +01:00
<entry>00:00:00.00+12</entry>
<entry>23:59:59.99-12</entry>
<entry>1 microsecond</entry>
</row>
</tbody>
</tgroup>
</table>
</para>
<para>
2001-12-23 21:21:37 +01:00
<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
effective limit of precision is determined by the underlying double
precision floating point number used to store values (in seconds
for <type>interval</type> and
2001-12-23 21:21:37 +01:00
in seconds since 2000-01-01 for <type>timestamp</type>). The
useful range of <replaceable>p</replaceable> is from 0 to about
6 for <type>timestamp</type>, but may be more for <type>interval</type>.
The system will accept <replaceable>p</replaceable> ranging from
0 to 13.
</para>
<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>.
</para>
1998-10-27 07:14:41 +01:00
<para>
To ensure an upgrade path from versions of
<productname>PostgreSQL</productname> earlier than 7.0,
we recognize <type>datetime</type>
(equivalent to <type>timestamp</type>) and
<type>timespan</type> (equivalent to <type>interval</type>).
These types are
now restricted to having an
implicit translation to <type>timestamp</type> and
<type>interval</type>, and
support for these will be removed in the next release of
<productname>PostgreSQL</productname> (likely named 7.3).
</para>
<para>
The types <type>abstime</type>
and <type>reltime</type> are lower precision types which are used internally.
You are discouraged from using any of 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>
1998-03-01 09:16:16 +01:00
<sect2 id="datatype-datetime-input">
<title>Date/Time Input</title>
1998-03-01 09:16:16 +01:00
<para>
Date and time input is accepted in almost any reasonable format, including
2001-11-28 21:49:10 +01:00
<acronym>ISO 8601</acronym>, <acronym>SQL</acronym>-compatible,
traditional <productname>PostgreSQL</productname>, and others.
For some formats, ordering of month and day in date input can be
ambiguous and there is support for specifying the expected
ordering of these fields.
The command
<literal>SET DateStyle TO 'US'</literal>
or <literal>SET DateStyle TO 'NonEuropean'</literal>
specifies the variant <quote>month before day</quote>, the command
<literal>SET DateStyle TO 'European'</literal> sets the variant
<quote>day before month</quote>. The <literal>ISO</literal> style
2000-03-14 23:52:53 +01:00
is the default but this default can be changed at compile time or at run time.
</para>
<para>
<productname>PostgreSQL</productname> is more flexible in
handling date/time 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>SQL9x</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.
</para>
<sect3>
<title><type>date</type></title>
<indexterm>
<primary>date</primary>
<secondary>data type</secondary>
</indexterm>
<para>
The following are some possible inputs for the <type>date</type> type.
2000-03-14 23:52:53 +01:00
<table tocentry="1">
<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</entry>
</row>
<row>
<entry>1999-01-08</entry>
<entry>ISO-8601 format, preferred</entry>
</row>
<row>
<entry>1/8/1999</entry>
2001-11-28 21:49:10 +01:00
<entry>U.S.; read as August 1 in European mode</entry>
</row>
<row>
<entry>8/1/1999</entry>
2001-11-28 21:49:10 +01:00
<entry>European; read as August 1 in U.S. mode</entry>
</row>
<row>
<entry>1/18/1999</entry>
2001-11-28 21:49:10 +01:00
<entry>U.S.; read as January 18 in any mode</entry>
</row>
<row>
<entry>19990108</entry>
<entry>ISO-8601 year, month, day</entry>
</row>
<row>
<entry>990108</entry>
<entry>ISO-8601 year, month, day</entry>
</row>
<row>
<entry>1999.008</entry>
<entry>Year and day of year</entry>
</row>
<row>
<entry>99008</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>
</para>
</sect3>
<sect3>
<title><type>time [ ( <replaceable>p</replaceable> ) ] [ without time zone ]</type></title>
<indexterm>
<primary>time</primary>
<secondary>data type</secondary>
</indexterm>
<indexterm>
<primary>time without time zone</primary>
<secondary>time</secondary>
</indexterm>
<para>
Per SQL99, this type can be specified as <type>time</type> or
as <type>time without time zone</type>. The optional precision
<replaceable>p</replaceable> should be between 0 and 13, and
defaults to the precision of the input time literal.
</para>
2000-03-14 23:52:53 +01:00
<para>
The following are valid <type>time</type> inputs.
<table tocentry="1">
<title>Time Input</title>
2000-03-14 23:52:53 +01:00
<tgroup cols="2">
<thead>
<row>
<entry>Example</entry>
<entry>Description</entry>
</row>
</thead>
<tbody>
<row>
<entry>04:05:06.789</entry>
2001-11-28 21:49:10 +01:00
<entry>ISO 8601</entry>
2000-03-14 23:52:53 +01:00
</row>
<row>
<entry>04:05:06</entry>
2001-11-28 21:49:10 +01:00
<entry>ISO 8601</entry>
2000-03-14 23:52:53 +01:00
</row>
<row>
<entry>04:05</entry>
2001-11-28 21:49:10 +01:00
<entry>ISO 8601</entry>
2000-03-14 23:52:53 +01:00
</row>
<row>
<entry>040506</entry>
2001-11-28 21:49:10 +01:00
<entry>ISO 8601</entry>
2000-03-14 23:52:53 +01:00
</row>
<row>
<entry>04:05 AM</entry>
<entry>Same as 04:05; AM does not affect value</entry>
</row>
<row>
<entry>04:05 PM</entry>
<entry>Same as 16:05; input hour must be <= 12</entry>
</row>
<row>
<entry>allballs</entry>
<entry>Same as 00:00:00</entry>
</row>
</tbody>
</tgroup>
</table>
</para>
</sect3>
<sect3>
<title><type>time [ ( <replaceable>precision</replaceable> ) ] with time zone</type></title>
<indexterm>
<primary>time with time zone</primary>
<secondary>data type</secondary>
</indexterm>
<indexterm>
<primary>time</primary>
<secondary>data type</secondary>
</indexterm>
2000-03-14 23:52:53 +01:00
<para>
This type is defined by SQL92, but the definition exhibits
properties which lead to questionable usefulness. In
2000-03-14 23:52:53 +01:00
most cases, a combination of <type>date</type>,
<type>time</type>, <type>timestamp without time zone</type>
and <type>timestamp with time zone</type>
2000-03-14 23:52:53 +01:00
should provide a complete range of date/time functionality
required by any application.
2000-03-14 23:52:53 +01:00
</para>
<para>
The optional precision
<replaceable>p</replaceable> should be between 0 and 13, and
defaults to the precision of the input time literal.
</para>
2000-03-14 23:52:53 +01:00
<para>
<type>time with time zone</type> accepts all input also legal
for the <type>time</type> type, appended with a legal time zone,
as follows:
<table tocentry="1">
<title>Time With Time Zone Input</title>
2000-03-14 23:52:53 +01:00
<tgroup cols="2">
<thead>
<row>
<entry>Example</entry>
<entry>Description</entry>
</row>
</thead>
<tbody>
<row>
2000-03-14 23:52:53 +01:00
<entry>04:05:06.789-8</entry>
2001-11-28 21:49:10 +01:00
<entry>ISO 8601</entry>
</row>
<row>
2000-03-14 23:52:53 +01:00
<entry>04:05:06-08:00</entry>
2001-11-28 21:49:10 +01:00
<entry>ISO 8601</entry>
</row>
<row>
2000-03-14 23:52:53 +01:00
<entry>04:05-08:00</entry>
2001-11-28 21:49:10 +01:00
<entry>ISO 8601</entry>
</row>
<row>
<entry>040506-08</entry>
2001-11-28 21:49:10 +01:00
<entry>ISO 8601</entry>
</row>
</tbody>
</tgroup>
</table>
</para>
2000-03-14 23:52:53 +01:00
<para>
Refer to <xref linkend="datatype-timezone-table"> for
2000-03-14 23:52:53 +01:00
more examples of time zones.
</para>
</sect3>
<sect3>
<title><type>timestamp [ (<replaceable>precision</replaceable>) ] without time zone</type></title>
<indexterm>
<primary>timestamp without time zone</primary>
<secondary>data type</secondary>
</indexterm>
<para>
Valid input for the <type>timestamp [ (<replaceable>p</replaceable>) ] without time zone</type>
type consists of a concatenation
of a date and a time, followed by an optional <literal>AD</literal> or
<literal>BC</literal>, followed by an optional time zone. (See below.)
Thus
2001-11-09 00:36:55 +01:00
<programlisting>
1999-01-08 04:05:06
2001-11-09 00:36:55 +01:00
</programlisting>
is a valid <type>timestamp without time zone</type> value that
is <acronym>ISO</acronym>-compliant.
In addition, the wide-spread format
2001-11-09 00:36:55 +01:00
<programlisting>
January 8 04:05:06 1999 PST
2001-11-09 00:36:55 +01:00
</programlisting>
is supported.
</para>
<para>
The optional precision
<replaceable>p</replaceable> should be between 0 and 13, and
defaults to the precision of the input <type>timestamp</type> literal.
</para>
<para>
For <type>timestamp without time zone</type>, any explicit time
zone specified in the input is silently swallowed. 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>
</sect3>
<sect3>
<title><type>timestamp [ (<replaceable>precision</replaceable>) ] with time zone</type></title>
<indexterm>
<primary>timestamp</primary>
<secondary>data type</secondary>
</indexterm>
<para>
Valid input for the <type>timestamp</type> type consists of a concatenation
of a date and a time, followed by an optional <literal>AD</literal> or
<literal>BC</literal>, followed by an optional time zone. (See below.)
Thus
2001-11-09 00:36:55 +01:00
<programlisting>
1999-01-08 04:05:06 -8:00
2001-11-09 00:36:55 +01:00
</programlisting>
is a valid <type>timestamp</type> value that is <acronym>ISO</acronym>-compliant.
In addition, the wide-spread format
2001-11-09 00:36:55 +01:00
<programlisting>
January 8 04:05:06 1999 PST
2001-11-09 00:36:55 +01:00
</programlisting>
is supported.
</para>
<para>
The optional precision
<replaceable>p</replaceable> should be between 0 and 13, and
defaults to the precision of the input <type>timestamp</type> literal.
</para>
<para>
<table tocentry="1" id="datatype-timezone-table">
<title>Time Zone Input</title>
<tgroup cols="2">
<thead>
<row>
<entry>Time Zone</entry>
<entry>Description</entry>
</row>
</thead>
<tbody>
<row>
<entry>PST</entry>
<entry>Pacific Standard Time</entry>
</row>
<row>
<entry>-8:00</entry>
<entry>ISO-8601 offset for PST</entry>
</row>
<row>
<entry>-800</entry>
<entry>ISO-8601 offset for PST</entry>
</row>
<row>
<entry>-8</entry>
<entry>ISO-8601 offset for PST</entry>
</row>
</tbody>
</tgroup>
</table>
</para>
</sect3>
<sect3>
2001-12-23 21:21:37 +01:00
<title><type>interval [ ( <replaceable>precision</replaceable> ) ]</type></title>
<indexterm>
<primary>interval</primary>
</indexterm>
<para>
<type>interval</type> values can be written with the following syntax:
2001-11-09 00:36:55 +01:00
<programlisting>
Quantity Unit [Quantity Unit...] [Direction]
@ Quantity Unit [Quantity Unit...] [Direction]
2001-11-09 00:36:55 +01:00
</programlisting>
2001-12-23 21:21:37 +01:00
where: <literal>Quantity</literal> is a number (possibly signed),
<literal>Unit</literal> 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;
<literal>Direction</literal> can be <literal>ago</literal> or
empty. The at sign (<literal>@</>) is optional noise. The amounts
2001-11-19 10:05:02 +01:00
of different units are implicitly added up with appropriate
sign accounting.
</para>
<para>
Quantities of days, hours, minutes, and seconds can be specified without
2001-11-19 10:05:02 +01:00
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>
2001-12-23 21:21:37 +01:00
<para>
The optional precision
<replaceable>p</replaceable> should be between 0 and 13, 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
input for the corresponding data type: <literal>CURRENT_DATE</literal>,
<literal>CURRENT_TIME</literal>,
<literal>CURRENT_TIMESTAMP</literal>. The latter two accept an
optional precision specification.
</para>
<para>
<productname>PostgreSQL</productname> also supports several
special constants for convenience.
<table tocentry="1">
<title>Special Date/Time Constants</title>
<tgroup cols="2">
<thead>
<row>
<entry>Constant</entry>
<entry>Description</entry>
</row>
</thead>
<tbody>
<row>
<entry>epoch</entry>
<entry>1970-01-01 00:00:00+00 (Unix system time zero)</entry>
</row>
<row>
<entry>infinity</entry>
<entry>Later than other valid times</entry>
</row>
<row>
<entry>-infinity</entry>
<entry>Earlier than other valid times</entry>
</row>
<row>
<entry>invalid</entry>
<entry>Illegal entry</entry>
</row>
<row>
<entry>now</entry>
<entry>Current transaction time</entry>
</row>
<row>
<entry>today</entry>
<entry>Midnight today</entry>
</row>
<row>
<entry>tomorrow</entry>
<entry>Midnight tomorrow</entry>
</row>
<row>
<entry>yesterday</entry>
<entry>Midnight yesterday</entry>
</row>
<row>
<entry>zulu, allballs, z</entry>
<entry>00:00:00.00 GMT</entry>
</row>
</tbody>
</tgroup>
</table>
<literal>'now'</literal> is
evaluated when the value is first interpreted.
2001-11-28 21:49:10 +01:00
</para>
2001-11-28 21:49:10 +01:00
<note>
<para>
As of <productname>PostgreSQL</> version 7.2,
<literal>'current'</literal> is no longer supported as a
date/time constant.
Previously,
<literal>'current'</literal> was stored as a special value,
and evaluated to <literal>'now'</literal> only when
2001-11-28 21:49:10 +01:00
used in an expression or type
conversion.
</para>
2001-11-28 21:49:10 +01:00
</note>
</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>
Output formats can be set to one of the four styles
2001-11-28 21:49:10 +01:00
ISO 8601, <acronym>SQL</acronym> (Ingres), traditional
PostgreSQL, and German, using the <command>SET DateStyle</command>.
The default is the <acronym>ISO</acronym> format.
<table tocentry="1">
<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 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>'PostgreSQL'</entry>
<entry>Original style</entry>
<entry>Wed Dec 17 07:37:16 1997 PST</entry>
</row>
<row>
<entry>'German'</entry>
<entry>Regional style</entry>
<entry>17.12.1997 07:37:16.00 PST</entry>
</row>
</tbody>
</tgroup>
</table>
</para>
<para>
The output of the <type>date</type> and <type>time</type> styles
is of course
only the date or time part in accordance with the above examples.
</para>
1998-03-01 09:16:16 +01:00
<para>
The <acronym>SQL</acronym> style has European and non-European
2001-11-28 21:49:10 +01:00
(U.S.) variants,
which determines whether month follows day or vice versa. (See
also <xref linkend="datatype-datetime-input">
for how this setting affects interpretation of
input values.)
1998-03-01 09:16:16 +01:00
<table tocentry="1">
2001-11-28 21:49:10 +01:00
<title>Date-Order Conventions</title>
<tgroup cols="3">
<thead>
<row>
<entry>Style Specification</entry>
<entry>Description</entry>
<entry>Example</entry>
</row>
</thead>
<tbody>
<row>
<entry>European</entry>
<entry><replaceable>day</replaceable>/<replaceable>month</replaceable>/<replaceable>year</replaceable></entry>
<entry>17/12/1997 15:37:16.00 MET</entry>
</row>
<row>
<entry>US</entry>
<entry><replaceable>month</replaceable>/<replaceable>day</replaceable>/<replaceable>year</replaceable></entry>
<entry>12/17/1997 07:37:16.00 PST</entry>
</row>
</tbody>
</tgroup>
</table>
</para>
1998-03-01 09:16:16 +01:00
<para>
<type>interval</type> output looks like the input format, except that units like
<literal>week</literal> or <literal>century</literal> are converted to years and days.
In ISO mode the output looks like
<programlisting>
[ Quantity Units [ ... ] ] [ Days ] Hours:Minutes [ ago ]
</programlisting>
</para>
<para>
There are several ways to affect the appearance of date/time types:
<itemizedlist spacing="compact" mark="bullet">
<listitem>
<para>
The <envar>PGDATESTYLE</envar> environment variable used by the backend directly
2000-08-29 22:02:09 +02:00
on postmaster start-up.
</para>
</listitem>
<listitem>
<para>
The <envar>PGDATESTYLE</envar> environment variable used by the frontend <application>libpq</application>
2000-08-29 22:02:09 +02:00
on session start-up.
</para>
</listitem>
<listitem>
<para>
<command>SET DATESTYLE</command> <acronym>SQL</acronym> command.
</para>
</listitem>
</itemizedlist>
</para>
</sect2>
<sect2 id="datatype-timezones">
<title>Time Zones</title>
<indexterm zone="datatype-timezones">
<primary>time zones</primary>
</indexterm>
<para>
<productname>PostgreSQL</productname> endeavors to be compatible with
<acronym>SQL92</acronym> definitions for typical usage.
However, the <acronym>SQL92</acronym> standard has an odd mix of date and
time types and capabilities. Two obvious problems are:
1998-03-01 09:16:16 +01:00
<itemizedlist>
<listitem>
<para>
Although the <type>date</type> type
does not have an associated time zone, the
2001-11-19 10:05:02 +01:00
<type>time</type> type can.
2000-11-11 20:50:31 +01:00
Time zones in the real world can have no meaning unless
associated with a date as well as a time
2001-11-28 21:49:10 +01:00
since the offset may vary through the year with daylight-saving
2000-11-11 20:50:31 +01:00
time boundaries.
</para>
</listitem>
1998-03-01 09:16:16 +01:00
<listitem>
<para>
The default time zone is specified as a constant integer offset
2001-11-28 21:49:10 +01:00
from GMT/UTC. It is not possible to adapt to daylight-saving
2000-11-11 20:50:31 +01:00
time when doing date/time arithmetic across
<acronym>DST</acronym> boundaries.
</para>
</listitem>
</itemizedlist>
</para>
<para>
2000-11-11 20:50:31 +01:00
To address these difficulties, we recommend using date/time
types that contain both date and time when using time zones. We
2001-11-28 21:49:10 +01:00
recommend <emphasis>not</emphasis> using the SQL92 type <type>time
with time zone</type> (though it is supported by
<productname>PostgreSQL</productname> for legacy applications and
2000-11-11 20:50:31 +01:00
for compatibility with other RDBMS implementations).
<productname>PostgreSQL</productname>
assumes your local time zone for any type containing only
date or time. Further, time zone support is derived from
the underlying operating system
2001-11-28 21:49:10 +01:00
time-zone capabilities, and hence can handle daylight-saving time
and other expected behavior.
</para>
<para>
2001-11-28 21:49:10 +01:00
<productname>PostgreSQL</productname> obtains time-zone support
from the underlying operating system for dates between 1902 and
2038 (near the typical date limits for Unix-style
systems). Outside of this range, all dates are assumed to be
specified and used in Universal Coordinated Time (UTC).
</para>
<para>
2000-11-11 20:50:31 +01:00
All dates and times are stored internally in UTC,
traditionally known as Greenwich Mean Time (GMT).
Times are converted to local time on the database server before being
sent to the client frontend, hence by default are in the server
time zone.
</para>
<para>
2001-11-28 21:49:10 +01:00
There are several ways to affect the time-zone behavior:
<itemizedlist spacing="compact" mark="bullet">
<listitem>
<para>
The <envar>TZ</envar> environment variable is used by the backend directly
2000-08-29 22:02:09 +02:00
on postmaster start-up as the default time zone.
</para>
</listitem>
<listitem>
<para>
The <envar>PGTZ</envar> environment variable, if set at the client, is used by libpq
to send a <command>SET TIME ZONE</command> command to the backend 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>
2000-11-11 20:50:31 +01:00
<listitem>
<para>
The <acronym>SQL92</acronym> qualifier on
2001-11-09 00:36:55 +01:00
<programlisting>
2000-11-11 20:50:31 +01:00
<replaceable>timestamp</replaceable> AT TIME ZONE '<replaceable>zone</replaceable>'
2001-11-09 00:36:55 +01:00
</programlisting>
2000-11-11 20:50:31 +01:00
where <replaceable>zone</replaceable> can be specified as a
text time zone (e.g. <literal>'PST'</literal>) or as an
interval (e.g. <literal>INTERVAL '-08:00'</literal>).
</para>
</listitem>
</itemizedlist>
</para>
2000-11-11 20:50:31 +01:00
<note>
<para>
If an invalid time zone is specified,
the time zone becomes GMT (on most systems anyway).
</para>
</note>
<note>
<para>
If the runtime option <literal>AUSTRALIAN_TIMEZONES</literal> is set
then <literal>CST</literal> and <literal>EST</literal> refer to
Australian time zones, not American ones.
</para>
</note>
</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 4713BC
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
<acronym>SQL99</acronym> type <type>boolean</type>.
<type>boolean</type> can have one of only two states:
<quote>true</quote> or <quote>false</quote>. A third state,
<quote>unknown</quote>, is represented by the
<acronym>SQL</acronym> NULL state.
</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 types represent two-dimensional spatial objects.
The most fundamental type,
the point, forms the basis for all of the other types.
</para>
<para>
<table tocentry="1">
<title>Geometric Types</title>
<tgroup cols="4">
<thead>
<row>
<entry>Geometric Type</entry>
<entry>Storage</entry>
<entry>Representation</entry>
<entry>Description</entry>
</row>
</thead>
<tbody>
<row>
<entry><type>point</type></entry>
<entry>16 bytes</entry>
<entry>(x,y)</entry>
<entry>Point in space</entry>
</row>
<row>
<entry><type>line</type></entry>
<entry>32 bytes</entry>
<entry>((x1,y1),(x2,y2))</entry>
<entry>Infinite line</entry>
</row>
<row>
<entry><type>lseg</type></entry>
<entry>32 bytes</entry>
<entry>((x1,y1),(x2,y2))</entry>
<entry>Finite line segment</entry>
</row>
<row>
<entry><type>box</type></entry>
<entry>32 bytes</entry>
<entry>((x1,y1),(x2,y2))</entry>
<entry>Rectangular box</entry>
</row>
<row>
<entry><type>path</type></entry>
<entry>4+32n bytes</entry>
<entry>((x1,y1),...)</entry>
<entry>Closed path (similar to polygon)</entry>
</row>
<row>
<entry><type>path</type></entry>
<entry>4+32n bytes</entry>
<entry>[(x1,y1),...]</entry>
<entry>Open path</entry>
</row>
<row>
<entry><type>polygon</type></entry>
<entry>4+32n bytes</entry>
<entry>((x1,y1),...)</entry>
<entry>Polygon (similar to closed path)</entry>
</row>
<row>
<entry><type>circle</type></entry>
<entry>24 bytes</entry>
<entry><(x,y),r></entry>
<entry>Circle (center and radius)</entry>
</row>
</tbody>
</tgroup>
</table>
</para>
<para>
A rich set of functions and operators is available to perform various geometric
operations such as scaling, translation, rotation, and determining
intersections.
</para>
<sect2>
<title>Point</title>
1998-03-01 09:16:16 +01:00
<indexterm>
<primary>point</primary>
</indexterm>
<para>
Points are the fundamental two-dimensional building block for geometric types.
</para>
<para>
<type>point</type> is specified using the following syntax:
1998-03-01 09:16:16 +01:00
<synopsis>
( <replaceable>x</replaceable> , <replaceable>y</replaceable> )
<replaceable>x</replaceable> , <replaceable>y</replaceable>
</synopsis>
where the arguments are
<variablelist>
<varlistentry>
<term><replaceable>x</replaceable></term>
<listitem>
<para>
2001-11-28 21:49:10 +01:00
The x-axis coordinate as a floating-point number
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable>y</replaceable></term>
<listitem>
<para>
2001-11-28 21:49:10 +01:00
The y-axis coordinate as a floating-point number
</para>
</listitem>
</varlistentry>
</variablelist>
</para>
</sect2>
1998-03-01 09:16:16 +01:00
<sect2>
<title>Line Segment</title>
1998-03-01 09:16:16 +01:00
<indexterm>
<primary>line</primary>
</indexterm>
<para>
Line segments (<type>lseg</type>) are represented by pairs of points.
</para>
1998-03-01 09:16:16 +01:00
<para>
<type>lseg</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 the arguments are
<variablelist>
<varlistentry>
<term>(<replaceable>x1</replaceable>,<replaceable>y1</replaceable>)</term>
<term>(<replaceable>x2</replaceable>,<replaceable>y2</replaceable>)</term>
<listitem>
<para>
2001-11-28 21:49:10 +01:00
The end points of the line segment
</para>
</listitem>
</varlistentry>
</variablelist>
</para>
</sect2>
1998-03-01 09:16:16 +01:00
<sect2>
<title>Box</title>
1998-03-01 09:16:16 +01:00
<indexterm>
<primary>box (data type)</primary>
</indexterm>
<para>
Boxes are represented by pairs of points that are opposite
corners of the box.
</para>
1998-03-01 09:16:16 +01:00
<para>
<type>box</type> is specified using the following syntax:
1998-03-01 09:16:16 +01:00
<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 the arguments are
<variablelist>
<varlistentry>
<term>(<replaceable>x1</replaceable>,<replaceable>y1</replaceable>)</term>
<term>(<replaceable>x2</replaceable>,<replaceable>y2</replaceable>)</term>
<listitem>
<para>
2001-11-28 21:49:10 +01:00
Opposite corners of the box
</para>
</listitem>
</varlistentry>
</variablelist>
</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.
</para>
</sect2>
<sect2>
<title>Path</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. Functions
<function>popen(p)</function>
and
<function>pclose(p)</function>
are supplied to force a path to be open or closed, and functions
<function>isopen(p)</function>
and
<function>isclosed(p)</function>
are supplied to test for either type in a query.
</para>
<para>
<type>path</type> is 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 arguments are
<variablelist>
<varlistentry>
<term>(<replaceable>x</replaceable>,<replaceable>y</replaceable>)</term>
<listitem>
<para>
End points of the line segments comprising the path.
A leading square bracket ("[") indicates an open path, while
a leading parenthesis ("(") indicates a closed path.
</para>
</listitem>
</varlistentry>
</variablelist>
</para>
<para>
Paths are output using the first syntax.
</para>
</sect2>
<sect2>
<title>Polygon</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>
<type>polygon</type> is 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 arguments are
<variablelist>
<varlistentry>
<term>(<replaceable>x</replaceable>,<replaceable>y</replaceable>)</term>
<listitem>
<para>
End points of the line segments comprising the boundary of the
2001-11-28 21:49:10 +01:00
polygon
</para>
</listitem>
</varlistentry>
</variablelist>
</para>
<para>
Polygons are output using the first syntax.
</para>
</sect2>
1998-03-01 09:16:16 +01:00
<sect2>
<title>Circle</title>
1998-03-01 09:16:16 +01:00
<indexterm>
<primary>circle</primary>
</indexterm>
<para>
Circles are represented by a center point and a radius.
</para>
1998-03-01 09:16:16 +01:00
<para>
<type>circle</type> is specified using the following syntax:
1998-03-01 09:16:16 +01:00
<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 the arguments are
<variablelist>
<varlistentry>
<term>(<replaceable>x</replaceable>,<replaceable>y</replaceable>)</term>
<listitem>
<para>
2001-11-28 21:49:10 +01:00
Center of the circle
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable>r</replaceable></term>
<listitem>
<para>
2001-11-28 21:49:10 +01:00
Radius of the circle
</para>
</listitem>
</varlistentry>
</variablelist>
</para>
<para>
Circles are output using the first syntax.
</para>
</sect2>
</sect1>
<sect1 id="datatype-net-types">
<title>Network Address Data Types</title>
<indexterm zone="datatype-net-types">
<primary>network</primary>
<secondary>addresses</secondary>
</indexterm>
<para>
<productname>PostgreSQL</> offers data types to store IP and MAC
addresses. It is preferable to use these types over plain text
types, because these types offer input error checking and several
specialized operators and functions.
<table tocentry="1" id="datatype-net-types-table">
<title>Network Address Data Types</title>
<tgroup cols="4">
<thead>
<row>
<entry>Name</entry>
<entry>Storage</entry>
<entry>Description</entry>
<entry>Range</entry>
</row>
</thead>
<tbody>
<row>
<entry><type>cidr</type></entry>
<entry>12 bytes</entry>
<entry>IP networks</entry>
<entry>valid IPv4 networks</entry>
</row>
<row>
<entry><type>inet</type></entry>
<entry>12 bytes</entry>
<entry>IP hosts and networks</entry>
<entry>valid IPv4 hosts or networks</entry>
</row>
<row>
<entry><type>macaddr</type></entry>
<entry>6 bytes</entry>
<entry>MAC addresses</entry>
<entry>customary formats</entry>
</row>
</tbody>
</tgroup>
</table>
</para>
<para>
IP v6 is not supported, yet.
</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 IP host address, and
optionally the identity of the subnet it is in, all in one field.
The subnet identity is represented by the number of bits in the
network part of the address (the <quote>netmask</quote>). If the netmask is 32,
then the value does not indicate a subnet, only a single host.
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">x.x.x.x/y</replaceable> where <replaceable
class="parameter">x.x.x.x</replaceable> is an IP 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, and the value represents just a single host.
On display, the <replaceable class="parameter">/y</replaceable>
portion is suppressed if the netmask is 32.
</para>
</sect2>
<sect2 id="datatype-cidr">
<title><type>cidr</></title>
<indexterm>
<primary>cidr</primary>
</indexterm>
<para>
The <type>cidr</type> type holds an IP network specification.
Input and output formats follow Classless Internet Domain Routing
conventions.
The format for
specifying classless networks is <replaceable
class="parameter">x.x.x.x/y</> where <replaceable
class="parameter">x.x.x.x</> is the network 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 numbering system, except
that it will be at least large enough to include all of the octets
written in the input.
</para>
<para>
Here are some examples:
1998-10-27 07:14:41 +01:00
<table tocentry="1">
<title><type>cidr</> Type Input Examples</title>
<tgroup cols="3">
<thead>
<row>
<entry><type>CIDR</type> Input</entry>
<entry><type>CIDR</type> Displayed</entry>
<entry><function>abbrev</function>(<type>CIDR</type>)</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>
</tbody>
</tgroup>
</table>
</para>
2000-11-11 20:50:31 +01:00
</sect2>
<sect2 id="datatype-inet-vs-cidr">
2000-11-12 00:27:48 +01:00
<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.
<tip>
<para>
If you do not like the output format for <type>inet</type> or
<type>cidr</type> values, try the <function>host</>(),
<function>text</>(), and <function>abbrev</>() functions.
</para>
</tip>
</para>
</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 strings</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>x</replaceable>)</type> and <type>BIT
VARYING(<replaceable>x</replaceable>)</type>; where
<replaceable>x</replaceable> is a positive integer.
</para>
<para>
<type>BIT</type> type data must match the length
<replaceable>x</replaceable> exactly; it is an error to attempt to
store shorter or longer bit strings. <type>BIT VARYING</type> is
of variable length up to the maximum length
<replaceable>x</replaceable>; longer strings will be rejected.
<type>BIT</type> without length is equivalent to
<literal>BIT(1)</literal>, <type>BIT VARYING</type> without length
specification means unlimited length.
</para>
<note>
<para>
Prior to <productname>PostgreSQL</> 7.2, <type>BIT</type> type data was
zero-padded on the right. This was changed to comply with the
SQL standard. To implement zero-padded bit strings, a
combination of the concatenation operator and the
<function>substring</function> function can be used.
</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 does not match type bit(3)
</computeroutput>
SELECT SUBSTRING(b FROM 1 FOR 2) FROM test;
</programlisting>
</example>
</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:
-->