postgresql/doc/src/sgml/datatype.sgml

2033 lines
57 KiB
Plaintext
Raw Normal View History

<!--
$Header: /cvsroot/pgsql/doc/src/sgml/datatype.sgml,v 1.49 2001/02/10 18:02:35 petere 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
<para>
<productname>Postgres</productname> has a rich set of native data
types available to users.
Users may add new types to <productname>Postgres</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
available to users. Most of the alternative names listed in the
<quote>Aliases</quote> column are the names used internally by
<productname>Postgres</productname> for historical reasons. In
addition, some internally used or deprecated types are available,
but they are not documented here. Many of the built-in types have
obvious external formats. However, several types are either unique
to <productname>Postgres</productname>, such as open and closed
paths, or have several possibilities for formats, such as the date
and time types.
</para>
<para>
<table id="datatype-table">
<title><productname>Postgres</productname> Data Types</title>
<titleabbrev>Data Types</titleabbrev>
<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>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>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</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></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 [ without time zone ]</type></entry>
<entry></entry>
<entry>time of day</entry>
</row>
<row>
<entry><type>time with time zone</type></entry>
<entry></entry>
<entry>time of day, including time zone</entry>
</row>
<row>
<entry><type>timestamp [ with time zone ]</type></entry>
<entry></entry>
<entry>date and time</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>
Most of the input and output functions corresponding to the
base types (e.g., integers and floating point numbers) do some
error-checking.
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
<para>
2000-03-14 23:52:53 +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>
1998-03-01 09:16:16 +01:00
<sect1 id="datatype-numeric">
<title>Numeric Types</title>
1998-03-01 09:16:16 +01:00
<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><productname>Postgres</productname> Numeric Types</title>
<titleabbrev>Numerics</titleabbrev>
<tgroup cols="4">
<thead>
<row>
<entry>Numeric Type</entry>
<entry>Storage</entry>
<entry>Description</entry>
<entry>Range</entry>
</row>
</thead>
<tbody>
1999-10-13 04:44:23 +02:00
<row>
<entry>smallint</entry>
<entry>2 bytes</entry>
<entry>Fixed-precision</entry>
<entry>-32768 to +32767</entry>
</row>
<row>
<entry>integer</entry>
<entry>4 bytes</entry>
<entry>Usual choice for fixed-precision</entry>
<entry>-2147483648 to +2147483647</entry>
</row>
<row>
<entry>bigint</entry>
<entry>8 bytes</entry>
<entry>Very large range fixed-precision</entry>
<entry>about 18 decimal places</entry>
</row>
<row>
<entry>decimal</entry>
<entry>variable</entry>
<entry>User-specified precision</entry>
<entry>no limit</entry>
1999-10-13 04:44:23 +02:00
</row>
<row>
<entry>numeric</entry>
<entry>variable</entry>
<entry>User-specified precision</entry>
<entry>no limit</entry>
</row>
<row>
<entry>real</entry>
<entry>4 bytes</entry>
<entry>Variable-precision</entry>
<entry>6 decimal places</entry>
</row>
<row>
<entry>double precision</entry>
<entry>8 bytes</entry>
<entry>Variable-precision</entry>
<entry>15 decimal places</entry>
</row>
<row>
<entry>serial</entry>
<entry>4 bytes</entry>
<entry>Identifer or cross-reference</entry>
<entry>0 to +2147483647</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.
</para>
<para>
The <type>bigint</type> type may not be available on all platforms since
it relies on compiler support for eight-byte integers.
</para>
<sect2 id="datatype-serial">
<title>The Serial Type</title>
<para>
The <type>serial</type> type is a special-case type constructed by
<productname>Postgres</productname> from other existing components.
It is typically used to create unique identifiers for table entries.
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');
CREATE UNIQUE INDEX <replaceable class="parameter">tablename</replaceable>_<replaceable class="parameter">colname</replaceable>_key on <replaceable class="parameter">tablename</replaceable> (<replaceable class="parameter">colname</replaceable>);
</programlisting>
<caution>
<para>
The implicit sequence created for the <type>serial</type> type will
<emphasis>not</emphasis> be automatically removed when the
table is dropped.
</para>
</caution>
Implicit sequences supporting the <type>serial</type> 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
<command>DROP SEQUENCE</command>.
</para>
</sect2>
</sect1>
<sect1 id="datatype-money">
<title>Monetary Type</title>
<note>
<title>Deprecated</title>
<para>
The <type>money</type> is now 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>Postgres</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><productname>Postgres</productname> Monetary Types</title>
<titleabbrev>Money</titleabbrev>
<tgroup cols="4">
<thead>
<row>
<entry>Monetary Type</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>
<para>
<acronym>SQL</acronym> defines two primary character types:
<type>character</type> and <type>character varying</type>.
<productname>Postgres</productname> supports these types, in
addition to the more general <type>text</type> type,
which unlike <type>character varying</type>
2000-03-14 23:52:53 +01:00
does not require an explicit declared upper
limit on the size of the field.
</para>
<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>
<para>
<table tocentry="1">
<title><productname>Postgres</productname> Character Types</title>
<titleabbrev>Characters</titleabbrev>
<tgroup cols="4">
<thead>
<row>
<entry>Character Type</entry>
<entry>Storage</entry>
<entry>Recommendation</entry>
<entry>Description</entry>
</row>
</thead>
<tbody>
<row>
<entry>character(n), char(n)</entry>
<entry>(4+n) bytes</entry>
<entry><acronym>SQL</acronym>-compatible</entry>
<entry>Fixed-length blank padded</entry>
</row>
<row>
<entry>character varying(n), varchar(n)</entry>
<entry>(4+n) bytes</entry>
<entry><acronym>SQL</acronym>-compatible</entry>
<entry>Variable-length with limit</entry>
</row>
<row>
<entry>text</entry>
<entry>(4+n) bytes</entry>
<entry>Most flexible</entry>
<entry>Variable unlimited length</entry>
</row>
</tbody>
</tgroup>
</table>
<note>
<para>
Although the type <type>text</type> is not SQL-compliant, many
other RDBMS packages have it as well.
</para>
</note>
</para>
<para>
There are two other fixed-length character types in
<productname>Postgres</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 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
<para>
<table tocentry="1">
<title><productname>Postgres</productname> Specialty Character Type</title>
<titleabbrev>Specialty Characters</titleabbrev>
<tgroup cols="3">
<thead>
<row>
<entry>Character Type</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>
</para>
</sect1>
<sect1 id="datatype-datetime">
<title>Date/Time Types</title>
<para>
<productname>Postgres</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><productname>Postgres</productname> Date/Time Types</title>
<titleabbrev>Date/Time</titleabbrev>
<tgroup cols="4">
<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</type></entry>
<entry>both date and time</entry>
<entry>8 bytes</entry>
<entry>4713 BC</entry>
<entry>AD 1465001</entry>
<entry>1 microsec / 14 digits</entry>
</row>
2000-03-14 23:52:53 +01:00
<row>
<entry><type>timestamp [ with time zone ]</type></entry>
<entry>date and time with time zone</entry>
2000-03-14 23:52:53 +01:00
<entry>8 bytes</entry>
<entry>1903 AD</entry>
<entry>2037 AD</entry>
<entry>1 microsec / 14 digits</entry>
</row>
<row>
<entry><type>interval</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 [ without time zone ]</type></entry>
<entry>times of day only</entry>
<entry>4 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 with time zone</type></entry>
<entry>times of day only</entry>
2000-03-14 23:52:53 +01:00
<entry>4 bytes</entry>
<entry>00:00:00.00+12</entry>
<entry>23:59:59.99-12</entry>
<entry>1 microsecond</entry>
</row>
</tbody>
</tgroup>
</table>
<note>
<para>
To ensure compatibility to earlier versions of <productname>Postgres</productname>
we also continue to provide <type>datetime</type> (equivalent to <type>timestamp</type>) and
<type>timespan</type> (equivalent to <type>interval</type>),
however support for these is now restricted to having an
implicit translation to <type>timestamp</type> and
<type>interval</type>.
The types <type>abstime</type>
and <type>reltime</type> are lower precision types which are used internally.
2000-03-14 23:52:53 +01:00
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>
</note>
</para>
1998-10-27 07:14:41 +01:00
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
2000-03-14 23:52:53 +01:00
<acronym>ISO-8601</acronym>, <acronym>SQL</acronym>-compatible,
traditional <productname>Postgres</productname>, and others.
The ordering of month and day in date input can be ambiguous, therefore a setting
exists to specify how it should be interpreted in ambiguous cases. The command
<literal>SET DateStyle TO 'US'</literal> or <literal>SET DateStyle TO 'NonEuropean'</literal>
specifies the variant "month before day", the command
<literal>SET DateStyle TO 'European'</literal> sets the variant
"day before month". 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>
See <xref linkend="datetime-appendix">
for the exact parsing rules of date/time input and for the recognized time zones.
</para>
<para>
Remember that any date or time input needs to be enclosed into
single quotes, like text strings. Refer to <xref
linkend="sql-syntax-constants-generic"> for more information.
SQL requires the following syntax
<synopsis>
<replaceable>type</replaceable> '<replaceable>value</replaceable>'
</synopsis>
but <productname>Postgres</productname> is more flexible.
</para>
<sect3>
<title>date</title>
<para>
The following are possible inputs for the <type>date</type> type.
2000-03-14 23:52:53 +01:00
<table tocentry="1">
<title><productname>Postgres</productname> Date Input</title>
<titleabbrev>Date Inputs</titleabbrev>
<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>
<entry>US; read as August 1 in European mode</entry>
</row>
<row>
<entry>8/1/1999</entry>
<entry>European; read as August 1 in US mode</entry>
</row>
<row>
<entry>1/18/1999</entry>
<entry>US; 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>January 8, 99 BC</entry>
<entry>Year 99 before the Common Era</entry>
</row>
</tbody>
</tgroup>
</table>
</para>
<para>
<table tocentry="1">
<title><productname>Postgres</productname> Month Abbreviations</title>
<titleabbrev>Month Abbreviations</titleabbrev>
<tgroup cols="2">
<thead>
<row>
<entry>Month</entry>
<entry>Abbreviations</entry>
</row>
</thead>
<tbody>
<row>
<entry>April</entry>
<entry>Apr</entry>
</row>
<row>
<entry>August</entry>
<entry>Aug</entry>
</row>
<row>
<entry>December</entry>
<entry>Dec</entry>
</row>
<row>
<entry>February</entry>
<entry>Feb</entry>
</row>
<row>
<entry>January</entry>
<entry>Jan</entry>
</row>
<row>
<entry>July</entry>
<entry>Jul</entry>
</row>
<row>
<entry>June</entry>
<entry>Jun</entry>
</row>
<row>
<entry>March</entry>
<entry>Mar</entry>
</row>
<row>
<entry>November</entry>
<entry>Nov</entry>
</row>
<row>
<entry>October</entry>
<entry>Oct</entry>
</row>
<row>
<entry>September</entry>
<entry>Sep, Sept</entry>
</row>
</tbody>
</tgroup>
</table>
<note>
<para>
The month <literal>May</literal> has no explicit abbreviation, for obvious reasons.
</para>
</note>
</para>
<para>
<table tocentry="1">
<title><productname>Postgres</productname> Day of Week Abbreviations</title>
<titleabbrev>Day of Week Abbreviations</titleabbrev>
<tgroup cols="2">
<thead>
<row>
<entry>Day</entry>
<entry>Abbreviation</entry>
</row>
</thead>
<tbody>
<row>
<entry>Sunday</entry>
<entry>Sun</entry>
</row>
<row>
<entry>Monday</entry>
<entry>Mon</entry>
</row>
<row>
<entry>Tuesday</entry>
<entry>Tue, Tues</entry>
</row>
<row>
<entry>Wednesday</entry>
<entry>Wed, Weds</entry>
</row>
<row>
<entry>Thursday</entry>
<entry>Thu, Thur, Thurs</entry>
</row>
<row>
<entry>Friday</entry>
<entry>Fri</entry>
</row>
<row>
<entry>Saturday</entry>
<entry>Sat</entry>
</row>
</tbody>
</tgroup>
</table>
</para>
</sect3>
<sect3>
<title>time [ without time zone ]</title>
<para>
Per SQL99, this type can be referenced as <type>time</type> and
as <type>time without time zone</type>.
</para>
2000-03-14 23:52:53 +01:00
<para>
The following are valid <type>time</type> inputs.
<table tocentry="1">
<title><productname>Postgres</productname> Time Input</title>
2000-03-14 23:52:53 +01:00
<titleabbrev>Time Inputs</titleabbrev>
<tgroup cols="2">
<thead>
<row>
<entry>Example</entry>
<entry>Description</entry>
</row>
</thead>
<tbody>
<row>
<entry>04:05:06.789</entry>
<entry>ISO-8601</entry>
</row>
<row>
<entry>04:05:06</entry>
<entry>ISO-8601</entry>
</row>
<row>
<entry>04:05</entry>
<entry>ISO-8601</entry>
</row>
<row>
<entry>040506</entry>
<entry>ISO-8601</entry>
</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>z</entry>
<entry>Same as 00:00:00</entry>
</row>
<row>
<entry>zulu</entry>
<entry>Same as 00:00:00</entry>
</row>
<row>
<entry>allballs</entry>
<entry>Same as 00:00:00</entry>
</row>
</tbody>
</tgroup>
</table>
</para>
</sect3>
<sect3>
<title>time with time zone</title>
2000-03-14 23:52:53 +01:00
<para>
This type is defined by SQL92, but the definition exhibits
fundamental deficiencies that render the type nearly useless. In
2000-03-14 23:52:53 +01:00
most cases, a combination of <type>date</type>,
<type>time</type>, and <type>timestamp</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>
<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><productname>Postgres</productname> Time With Time
2000-03-14 23:52:53 +01:00
Zone Input</title>
<titleabbrev>Time With Time Zone Inputs</titleabbrev>
<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>
<entry>ISO-8601</entry>
</row>
<row>
2000-03-14 23:52:53 +01:00
<entry>04:05:06-08:00</entry>
<entry>ISO-8601</entry>
</row>
<row>
2000-03-14 23:52:53 +01:00
<entry>04:05-08:00</entry>
<entry>ISO-8601</entry>
</row>
<row>
<entry>040506-08</entry>
<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>timestamp</title>
<para>
Valid input for the <type>timestamp</type> type consists of a concatenation
of a date and a time, followed by an optional <literal>AD</literal> or
<literal>BC</literal>, followed by an optional time zone. (See below.)
Thus
<programlisting>
1999-01-08 04:05:06 -8:00
</programlisting>
is a valid <type>timestamp</type> value that is <acronym>ISO</acronym>-compliant.
In addition, the wide-spread format
<programlisting>
January 8 04:05:06 1999 PST
</programlisting>
is supported.
</para>
<para>
<table tocentry="1" id="datatype-timezone-table">
<title><productname>Postgres</productname> Time Zone Input</title>
<titleabbrev>Time Zone Inputs</titleabbrev>
<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>
<title>interval</title>
<para>
<type>interval</type>s can be specified with the following syntax:
<programlisting>
Quantity Unit [Quantity Unit...] [Direction]
@ Quantity Unit [Direction]
</programlisting>
where: <literal>Quantity</literal> is ..., <literal>-1</literal>,
<literal>0</literal>, <literal>1</literal>, <literal>2</literal>, ...;
<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.
</para>
</sect3>
<sect3>
<title>Special values</title>
<para>
The following <acronym>SQL</acronym>-compatible functions can be used as date or time
input for the corresponding datatype: <literal>CURRENT_DATE</literal>,
<literal>CURRENT_TIME</literal>, <literal>CURRENT_TIMESTAMP</literal>.
</para>
<para>
<productname>Postgres</productname> also supports several special constants for
convenience.
<table tocentry="1">
<title><productname>Postgres</productname> Special Date/Time Constants</title>
<titleabbrev>Constants</titleabbrev>
<tgroup cols="2">
<thead>
<row>
<entry>Constant</entry>
<entry>Description</entry>
</row>
</thead>
<tbody>
<row>
<entry>current</entry>
<entry>Current transaction time, deferred</entry>
</row>
<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>
</tbody>
</tgroup>
</table>
<literal>'now'</literal> is resolved when the value is inserted, <literal>'current'</literal>
is resolved everytime the value is retrieved. So you probably want to use <literal>'now'</literal>
in most applications. (Of course you <emphasis>really</emphasis> want to use
<literal>CURRENT_TIMESTAMP</literal>, which is equivalent to <literal>'now'</literal>.)
</para>
</sect3>
</sect2>
<sect2 id="datatype-datetime-output">
<title>Date/Time Output</title>
<para>
Output formats can be set to one of the four styles
ISO-8601, <acronym>SQL</acronym> (Ingres), traditional
Postgres, and German, using the <command>SET DateStyle</command>.
The default is the <acronym>ISO</acronym> format.
<table tocentry="1">
<title><productname>Postgres</productname> Date/Time Output Styles</title>
<titleabbrev>Styles</titleabbrev>
<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>'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>
<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 (US) variants,
which determines whether month follows day or vica versa. (See also above
at Date/Time Input, how this setting affects interpretation of input values.)
1998-03-01 09:16:16 +01:00
<table tocentry="1">
<title><productname>Postgres</productname> Date Order Conventions</title>
<titleabbrev>Date Order</titleabbrev>
<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 libpq
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>
<para>
<productname>Postgres</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
<type>time</type> type can or does.
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
since the offset may vary through the year with daylight savings
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
2000-11-11 20:50:31 +01:00
from GMT/UTC. It is not possible to adapt to daylight savings
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
2000-11-11 20:50:31 +01:00
recommend <emphasis>not</emphasis> using the SQL92 type TIME
WITH TIME ZONE (though it is supported by
<productname>Postgres</productname> for legacy applications and
for compatibility with other RDBMS implementations).
<productname>Postgres</productname>
assumes local time for any type containing only
date or time. Further, time zone support is derived from
the underlying operating system
time zone capabilities, and hence can handle daylight savings time
and other expected behavior.
</para>
<para>
<productname>Postgres</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>
There are several ways to affect the time zone behavior:
<itemizedlist spacing="compact" mark="bullet">
<listitem>
<para>
2000-11-11 20:50:31 +01:00
The TZ 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 PGTZ environment variable set at the client used by libpq
to send time zone information 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
<programlisting>
<replaceable>timestamp</replaceable> AT TIME ZONE '<replaceable>zone</replaceable>'
</programlisting>
where <replaceable>zone</replaceable> can be specified as a
text time zone (e.g. <literal>'PST'</literal>) or as an
interval (e.g. <literal>INTERVAL '-08:00'</literal>).
</para>
</listitem>
</itemizedlist>
</para>
<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 compiler option USE_AUSTRALIAN_RULES is set
then <literal>EST</literal> refers to Australia Eastern Std Time,
which has an offset of +10:00 hours from UTC.
</para>
</note>
</para>
</sect2>
<sect2 id="datatype-datetime-internals">
<title>Internals</title>
<para>
<productname>Postgres</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 consistant enough to warrant coding into a date/time handler.
</para>
</sect2>
</sect1>
<sect1 id="datatype-boolean">
<title>Boolean Type</title>
<para>
<productname>Postgres</productname> supports the
<acronym>SQL99</acronym> <type>boolean</type> type.
<type>boolean</type> can have one of only two states: 'true' or
'false'. A third state, 'unknown', is represented by the SQL NULL
state. <type>boolean</type> can be used in any boolean expression,
and boolean expressions always evaluate to a result compatible
with this type.
</para>
<para>
<type>boolean</type> uses 1 byte of storage.
</para>
<para>
<table tocentry="1">
<title><productname>Postgres</productname> Boolean Type</title>
<titleabbrev>Booleans</titleabbrev>
<tgroup cols="3">
<thead>
<row>
<entry>State</entry>
<entry>Input</entry>
<entry>Output</entry>
</row>
</thead>
<tbody>
<row>
<entry>True</entry>
<entry>TRUE, 't', 'true', 'y', 'yes', '1'</entry>
<entry><literal>t</literal></entry>
</row>
<row>
<entry>False</entry>
<entry>FALSE, 'f', 'false', 'n', 'no', '0'</entry>
<entry><literal>f</literal></entry>
</row>
</tbody>
</tgroup>
</table>
</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><productname>Postgres</productname> Geometric Types</title>
<titleabbrev>Geometrics</titleabbrev>
<tgroup cols="4">
<thead>
<row>
<entry>Geometric Type</entry>
<entry>Storage</entry>
<entry>Representation</entry>
<entry>Description</entry>
</row>
</thead>
<tbody>
<row>
<entry>point</entry>
<entry>16 bytes</entry>
<entry>(x,y)</entry>
<entry>Point in space</entry>
</row>
<row>
<entry>line</entry>
<entry>32 bytes</entry>
<entry>((x1,y1),(x2,y2))</entry>
<entry>Infinite line</entry>
</row>
<row>
<entry>lseg</entry>
<entry>32 bytes</entry>
<entry>((x1,y1),(x2,y2))</entry>
<entry>Finite line segment</entry>
</row>
<row>
<entry>box</entry>
<entry>32 bytes</entry>
<entry>((x1,y1),(x2,y2))</entry>
<entry>Rectangular box</entry>
</row>
<row>
<entry>path</entry>
<entry>4+32n bytes</entry>
<entry>((x1,y1),...)</entry>
<entry>Closed path (similar to polygon)</entry>
</row>
<row>
<entry>path</entry>
<entry>4+32n bytes</entry>
<entry>[(x1,y1),...]</entry>
<entry>Open path</entry>
</row>
<row>
<entry>polygon</entry>
<entry>4+32n bytes</entry>
<entry>((x1,y1),...)</entry>
<entry>Polygon (similar to closed path)</entry>
</row>
<row>
<entry>circle</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
<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>
The x-axis coordinate as a floating point number.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable>y</replaceable></term>
<listitem>
<para>
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
<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>
The endpoints 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
<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>
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 lower left corner first and the upper right corner last.
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>
<para>
Paths are represented by connected sets of points. Paths can be "open", where
the first and last points in the set are not connected, and "closed",
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>
Endpoints 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>
<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>
Endpoints of the line segments comprising the boundary of the
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
<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>
Center of the circle.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable>r</replaceable></term>
<listitem>
<para>
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>
<para>
<productname>Postgres</> 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>cidr</entry>
<entry>12 bytes</entry>
<entry>IP networks</entry>
<entry>valid IPv4 networks</entry>
</row>
<row>
<entry>inet</entry>
<entry>12 bytes</entry>
<entry>IP hosts and networks</entry>
<entry>valid IPv4 hosts or networks</entry>
</row>
<row>
<entry>macaddr</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>
<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 "netmask"). 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>
<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>CIDR Input</entry>
<entry>CIDR Displayed</entry>
<entry>abbrev(CIDR)</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</></>
<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 <literal>'08002b:010203'</>,
<literal>'08002b-010203'</>, <literal>'0800.2b01.0203'</>,
<literal>'08-00-2b-01-02-03'</>, and
<literal>'08:00:2b:01:02:03'</>, 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
latter of the given forms.
</para>
<para>
The directory <filename class="directory">contrib/mac</filename>
in the <productname>Postgres</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>
<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>; the
<replaceable>x</replaceable> specifies the maximum length.
<type>BIT</type> type data is automatically padded with 0's on the
right to the maximum length, <type>BIT VARYING</type> is of
variable length. <type>BIT</type> without length is requivalent
to <literal>BIT(1)</literal>, <type>BIT VARYING</type> means
unlimited length. Input data that is longer than the allowed
length will be truncated. 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>
<informalexample>
<para>
Some examples:
<programlisting>
CREATE TABLE test (a BIT(3), b BIT VARYING(5));
INSERT INTO test VALUES (B'101', B'00');
SELECT SUBSTRING(b FROM 1 FOR 2) FROM test;
</programlisting>
</para>
</informalexample>
</sect1>
</chapter>
<!-- Keep this comment at the end of the file
Local variables:
mode:sgml
sgml-omittag:nil
sgml-shorttag:t
sgml-minimize-attributes:nil
sgml-always-quote-attributes:t
sgml-indent-step:1
sgml-indent-data:t
sgml-parent-document:nil
sgml-default-dtd-file:"./reference.ced"
sgml-exposed-tags:nil
sgml-local-catalogs:("/usr/lib/sgml/catalog")
sgml-local-ecat-files:nil
End:
-->