postgresql/doc/src/sgml/datatype.sgml

1576 lines
41 KiB
Plaintext
Raw Normal View History

<Chapter Id="datatype">
1998-03-01 09:16:16 +01:00
<Title>Data Types</Title>
<Abstract>
<Para>
Describes the built-in data types available in
<ProductName>Postgres</ProductName>.
1998-03-01 09:16:16 +01:00
</Para>
</Abstract>
<Para>
<ProductName>Postgres</ProductName> has a rich set of native data
types available to users.
1998-03-01 09:16:16 +01:00
Users may add new types to <ProductName>Postgres</ProductName> using the
<Command>define type</Command>
command described elsewhere.
<Para>
In the context of data types, the following sections will discuss
<acronym>SQL</acronym> standards compliance, porting issues, and usage.
1998-03-01 09:16:16 +01:00
Some <ProductName>Postgres</ProductName> types correspond directly to
<acronym>SQL92</acronym>-compatible types. In other
cases, data types defined by <acronym>SQL92</acronym> syntax are mapped directly
1998-03-01 09:16:16 +01:00
into native <ProductName>Postgres</ProductName> types.
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
1998-03-01 09:16:16 +01:00
several possibilities for formats, such as date and time types.
</Para>
<Para>
<TABLE TOCENTRY="1">
<TITLE><ProductName>Postgres</ProductName> Data Types</TITLE>
<TITLEABBREV>Data Types</TITLEABBREV>
<TGROUP COLS="3">
<THEAD>
<ROW>
<ENTRY><ProductName>Postgres</ProductName> Type</ENTRY>
<ENTRY><Acronym>SQL92</Acronym> or <Acronym>SQL3</Acronym> Type</ENTRY>
<ENTRY>Description</ENTRY>
</ROW>
</THEAD>
<TBODY>
<ROW>
<ENTRY>bool</ENTRY>
<ENTRY>boolean</ENTRY>
<ENTRY>logical boolean (true/false)</ENTRY>
</ROW>
<ROW>
<ENTRY>box</ENTRY>
<ENTRY></ENTRY>
<ENTRY>rectangular box in 2D plane</ENTRY>
</ROW>
<ROW>
<ENTRY>char(n)</ENTRY>
<ENTRY>character(n)</ENTRY>
<ENTRY>fixed-length character string</ENTRY>
</ROW>
1998-10-27 07:14:41 +01:00
<ROW>
<ENTRY>cidr</ENTRY>
<ENTRY></ENTRY>
<ENTRY>IP version 4 network or host address</ENTRY>
</ROW>
1998-03-01 09:16:16 +01:00
<ROW>
<ENTRY>circle</ENTRY>
<ENTRY></ENTRY>
<ENTRY>circle in 2D plane</ENTRY>
</ROW>
<ROW>
<ENTRY>date</ENTRY>
<ENTRY>date</ENTRY>
<ENTRY>calendar date without time of day</ENTRY>
</ROW>
<ROW>
<ENTRY>float4/8</ENTRY>
<ENTRY>float(p)</ENTRY>
<ENTRY>floating-point number with precision p</ENTRY>
</ROW>
<ROW>
<ENTRY>float8</ENTRY>
<ENTRY>real, double precision</ENTRY>
<ENTRY>double-precision floating-point number</ENTRY>
</ROW>
1998-10-27 07:14:41 +01:00
<ROW>
<ENTRY>inet</ENTRY>
<ENTRY></ENTRY>
<ENTRY>IP version 4 network or host address</ENTRY>
</ROW>
1998-03-01 09:16:16 +01:00
<ROW>
<ENTRY>int2</ENTRY>
<ENTRY>smallint</ENTRY>
<ENTRY>signed two-byte integer</ENTRY>
</ROW>
<ROW>
<ENTRY>int4</ENTRY>
<ENTRY>int, integer</ENTRY>
<ENTRY>signed 4-byte integer</ENTRY>
</ROW>
<ROW>
<ENTRY>int4</ENTRY>
<ENTRY>decimal(p,s)</ENTRY>
<ENTRY>exact numeric for p <= 9, s = 0</ENTRY>
</ROW>
<ROW>
<ENTRY>int4</ENTRY>
<ENTRY>numeric(p,s)</ENTRY>
<ENTRY>exact numeric for p == 9, s = 0</ENTRY>
</ROW>
<ROW>
<ENTRY>int8</ENTRY>
<ENTRY></ENTRY>
<ENTRY>signed 8-byte integer</ENTRY>
</ROW>
1998-03-01 09:16:16 +01:00
<ROW>
<ENTRY>line</ENTRY>
<ENTRY></ENTRY>
<ENTRY>infinite line in 2D plane</ENTRY>
</ROW>
<ROW>
<ENTRY>lseg</ENTRY>
<ENTRY></ENTRY>
<ENTRY>line segment in 2D plane</ENTRY>
</ROW>
<ROW>
<ENTRY>money</ENTRY>
<ENTRY>decimal(9,2)</ENTRY>
<ENTRY>US-style currency</ENTRY>
</ROW>
<ROW>
<ENTRY>path</ENTRY>
<ENTRY></ENTRY>
<ENTRY>open and closed geometric path in 2D plane</ENTRY>
</ROW>
<ROW>
<ENTRY>point</ENTRY>
<ENTRY></ENTRY>
<ENTRY>geometric point in 2D plane</ENTRY>
</ROW>
<ROW>
<ENTRY>polygon</ENTRY>
<ENTRY></ENTRY>
<ENTRY>closed geometric path in 2D plane</ENTRY>
</ROW>
<ROW>
<ENTRY>serial</ENTRY>
<ENTRY></ENTRY>
<ENTRY>unique id for indexing and cross-reference</ENTRY>
</ROW>
1998-03-01 09:16:16 +01:00
<ROW>
<ENTRY>time</ENTRY>
<ENTRY>time</ENTRY>
<ENTRY>time of day</ENTRY>
</ROW>
<ROW>
<ENTRY>timespan</ENTRY>
<ENTRY>interval</ENTRY>
<ENTRY>general-use time span</ENTRY>
</ROW>
<ROW>
<ENTRY>timestamp</ENTRY>
<ENTRY>timestamp with time zone</ENTRY>
<ENTRY>date/time</ENTRY>
</ROW>
<ROW>
<ENTRY>varchar(n)</ENTRY>
<ENTRY>character varying(n)</ENTRY>
<ENTRY>variable-length character string</ENTRY>
</ROW>
</TBODY>
</TGROUP>
</TABLE>
</Para>
1998-10-27 07:14:41 +01:00
<para>
<note>
<para>
The <type>cidr</type> and <type>inet</type> types are designed to handle any IP type
but only ipv4 is handled in the current implementation.
Everything here that talks about ipv4 will apply to ipv6 in a future release.
</note>
1998-03-01 09:16:16 +01:00
<Para>
<TABLE TOCENTRY="1">
<TITLE><ProductName>Postgres</ProductName> Function Constants</TITLE>
<TITLEABBREV>Constants</TITLEABBREV>
<TGROUP COLS="3">
<THEAD>
<ROW>
<ENTRY><ProductName>Postgres</ProductName> Function</ENTRY>
<ENTRY><Acronym>SQL92</Acronym> Constant</ENTRY>
<ENTRY>Description</ENTRY>
</ROW>
</THEAD>
<TBODY>
<ROW>
<ENTRY>getpgusername()</ENTRY>
<ENTRY>current_user</ENTRY>
<ENTRY>user name in current session</ENTRY>
</ROW>
<ROW>
<ENTRY>date('now')</ENTRY>
<ENTRY>current_date</ENTRY>
<ENTRY>date of current transaction</ENTRY>
</ROW>
<ROW>
<ENTRY>time('now')</ENTRY>
<ENTRY>current_time</ENTRY>
<ENTRY>time of current transaction</ENTRY>
</ROW>
<ROW>
<ENTRY>timestamp('now')</ENTRY>
<ENTRY>current_timestamp</ENTRY>
<ENTRY>date and time of current transaction</ENTRY>
</ROW>
</TBODY>
</TGROUP>
</TABLE>
</Para>
<Para>
<ProductName>Postgres</ProductName> has features at the forefront of
<acronym>ORDBMS</acronym> development. In addition to
<acronym>SQL3</acronym> conformance, substantial portions
of <acronym>SQL92</acronym> are also supported.
Although we strive for <acronym>SQL92</acronym> compliance,
there are some aspects of the standard
1998-03-01 09:16:16 +01:00
which are ill considered and which should not live through subsequent standards.
<ProductName>Postgres</ProductName> will not make great efforts to
conform to these features; however, these tend to apply in little-used
or obsure cases, and a typical user is not likely to run into them.
1998-03-01 09:16:16 +01:00
<Para>
Most of the input and output functions corresponding to the
1998-03-01 09:16:16 +01:00
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
1998-03-01 09:16:16 +01:00
silently underflow or overflow.
</Para>
<Para>
Note that some of the input and output functions are not invertible. That is,
1998-03-01 09:16:16 +01:00
the result of an output function may lose precision when compared to
the original input.
<note>
<para>
The original <ProductName>Postgres</ProductName> v4.2 code received from
Berkeley rounded all double precision floating point results to six digits for
output. Starting with v6.1, floating point numbers are allowed to retain
most of the intrinsic precision of the type (typically 15 digits for doubles,
6 digits for 4-byte floats).
Other types with underlying floating point fields (e.g. geometric
types) carry similar precision.
</note>
1998-03-01 09:16:16 +01:00
</Para>
<Sect1>
<Title>Numeric Types</Title>
<Para>
Numeric types consist of two- and four-byte integers and four- and eight-byte
floating point numbers.
<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>
<ROW>
<ENTRY>float4</ENTRY>
<ENTRY>4 bytes</ENTRY>
<ENTRY>Variable-precision</ENTRY>
<ENTRY>6 decimal places</ENTRY>
</ROW>
<ROW>
<ENTRY>float8</ENTRY>
<ENTRY>8 bytes</ENTRY>
<ENTRY>Variable-precision</ENTRY>
<ENTRY>15 decimal places</ENTRY>
</ROW>
1998-03-01 09:16:16 +01:00
<ROW>
<ENTRY>int2</ENTRY>
<ENTRY>2 bytes</ENTRY>
<ENTRY>Fixed-precision</ENTRY>
<ENTRY>-32768 to +32767</ENTRY>
</ROW>
<ROW>
<ENTRY>int4</ENTRY>
<ENTRY>4 bytes</ENTRY>
<ENTRY>Usual choice for fixed-precision</ENTRY>
<ENTRY>-2147483648 to +2147483647</ENTRY>
</ROW>
<ROW>
<ENTRY>int8</ENTRY>
<ENTRY>8 bytes</ENTRY>
<ENTRY>Very large range fixed-precision</ENTRY>
<ENTRY>+/- &gt; 18 decimal places</ENTRY>
</ROW>
1998-03-01 09:16:16 +01:00
<ROW>
<ENTRY>serial</ENTRY>
1998-03-01 09:16:16 +01:00
<ENTRY>4 bytes</ENTRY>
<ENTRY>Identifer or cross-reference</ENTRY>
<ENTRY>0 to +2147483647</ENTRY>
1998-03-01 09:16:16 +01:00
</ROW>
</TBODY>
</TGROUP>
</TABLE>
</Para>
<para>
The numeric types have a full set of corresponding arithmetic operators and
functions. Refer to <xref linkend="math-opers" endterm="math-opers">
and <xref linkend="math-funcs" endterm="math-funcs"> for more information.
<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> INT4 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.
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>.
</caution>
1998-03-01 09:16:16 +01:00
<Para>
The <FirstTerm>exact numerics</FirstTerm> <Type>decimal</Type> and
<Type>numeric</Type>
have fully implemented syntax but currently
(<ProductName>Postgres</ProductName> v6.4)
1998-03-01 09:16:16 +01:00
support only a small range of precision and/or range values.
The <type>int8</type> type may not be available on all platforms since
it relies on compiler support for this.
1998-03-01 09:16:16 +01:00
</Para>
</Sect1>
<Sect1>
<Title>Monetary Type</Title>
<Para>
The <Type>money</Type> type supports US-style currency with
fixed decimal point representation.
If <ProductName>Postgres</ProductName> is compiled with USE_LOCALE
then the money type
should use the monetary conventions defined for
<citetitle>locale(7)</citetitle>.
1998-03-01 09:16:16 +01:00
<Para>
<TABLE TOCENTRY="1">
<TITLE><ProductName>Postgres</ProductName> Numeric Types</TITLE>
<TITLEABBREV>Numerics</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>
<Para>
<type>numeric</type>
should eventually replace the money type. It has a
fully implemented syntax but currently
(<ProductName>Postgres</ProductName> v6.4)
support only a small range of precision and/or range values
and cannot adequately substitute for the money type.
1998-03-01 09:16:16 +01:00
</Para>
</Sect1>
<Sect1>
<Title>Character Types</Title>
<Para>
<Acronym>SQL92</Acronym> defines two primary character types:
<Type>char</Type> and <Type>varchar</Type>.
<ProductName>Postgres</ProductName> supports these types, in
addition to the more general <Type>text</Type> type,
which unlike <Type>varchar</Type>
1998-03-01 09:16:16 +01:00
does not require an upper
limit to be declared on the size of the field.
</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>char</ENTRY>
<ENTRY>1 byte</ENTRY>
<ENTRY><acronym>SQL92</acronym>-compatible</ENTRY>
1998-03-01 09:16:16 +01:00
<ENTRY>Single character</ENTRY>
</ROW>
<ROW>
<ENTRY>char(n)</ENTRY>
<ENTRY>(4+n) bytes</ENTRY>
<ENTRY><acronym>SQL92</acronym>-compatible</ENTRY>
1998-03-01 09:16:16 +01:00
<ENTRY>Fixed-length blank padded</ENTRY>
</ROW>
<ROW>
<ENTRY>text</ENTRY>
<ENTRY>(4+x) bytes</ENTRY>
<ENTRY>Best choice</ENTRY>
<ENTRY>Variable-length</ENTRY>
</ROW>
<ROW>
<ENTRY>varchar(n)</ENTRY>
<ENTRY>(4+n) bytes</ENTRY>
<ENTRY><acronym>SQL92</acronym>-compatible</ENTRY>
1998-03-01 09:16:16 +01:00
<ENTRY>Variable-length with limit</ENTRY>
</ROW>
</TBODY>
</TGROUP>
</TABLE>
</Para>
<Para>
There is one other fixed-length character type.
The <Type>name</Type> type
only has one purpose and that is to provide
<ProductName>Postgres</ProductName> with a
special type to use for internal names.
It is not intended for use by the general user.
It's length is currently defined as 32 chars
but should be reference using NAMEDATALEN.
1998-08-17 18:12:35 +02:00
This is set at compile time and may change in a future release.
1998-03-01 09:16:16 +01:00
</Para>
<Para>
<TABLE TOCENTRY="1">
<TITLE><ProductName>Postgres</ProductName> Specialty Character Type</TITLE>
1998-03-01 09:16:16 +01:00
<TITLEABBREV>Specialty Characters</TITLEABBREV>
<TGROUP COLS="3">
<THEAD>
<ROW>
<ENTRY>Character Type</ENTRY>
<ENTRY>Storage</ENTRY>
<ENTRY>Description</ENTRY>
</ROW>
</THEAD>
<TBODY>
<ROW>
<ENTRY>name</ENTRY>
<ENTRY>32 bytes</ENTRY>
<ENTRY>Thirty-two character internal type</ENTRY>
1998-03-01 09:16:16 +01:00
</ROW>
</TBODY>
</TGROUP>
</TABLE>
</Para>
</Sect1>
<Sect1>
<Title>Date/Time Types</Title>
<Para>
There are two fundamental kinds of date and time measurements:
1998-10-27 07:14:41 +01:00
absolute clock times and relative time intervals.
Both quantities should demonstrate continuity and smoothness, as does time itself.
<ProductName>Postgres</ProductName> supplies two primary user-oriented
date and time types,
1998-10-27 07:14:41 +01:00
<Type>datetime</Type> and <Type>timespan</Type>, as well as
the related <acronym>SQL92</acronym> types <Type>timestamp</Type>,
<Type>interval</Type>,
<Type>date</Type> and <Type>time</Type>.
1998-03-01 09:16:16 +01:00
</Para>
<Para>
1998-10-27 07:14:41 +01:00
In a future release, <Type>datetime</Type> and <Type>timespan</Type> are likely
to merge with the <acronym>SQL92</acronym> types <Type>timestamp</Type>,
<Type>interval</Type>.
Other date and time types are also available, mostly
1998-03-01 09:16:16 +01:00
for historical reasons.
</Para>
<Para>
<TABLE TOCENTRY="1">
<TITLE><ProductName>Postgres</ProductName> Date/Time Types</TITLE>
<TITLEABBREV>Date/Time</TITLEABBREV>
<TGROUP COLS="4">
<THEAD>
<ROW>
<ENTRY>Date/Time Type</ENTRY>
<ENTRY>Storage</ENTRY>
<ENTRY>Recommendation</ENTRY>
<ENTRY>Description</ENTRY>
</ROW>
</THEAD>
<TBODY>
<ROW>
<ENTRY>abstime</ENTRY>
<ENTRY>4 bytes</ENTRY>
<ENTRY>original date and time</ENTRY>
<ENTRY>limited range</ENTRY>
</ROW>
<ROW>
<ENTRY>date</ENTRY>
<ENTRY>4 bytes</ENTRY>
<ENTRY><acronym>SQL92</acronym> type</ENTRY>
1998-03-01 09:16:16 +01:00
<ENTRY>wide range</ENTRY>
</ROW>
<ROW>
<ENTRY>datetime</ENTRY>
<ENTRY>8 bytes</ENTRY>
<ENTRY>best general date and time</ENTRY>
<ENTRY>wide range, high precision</ENTRY>
</ROW>
<ROW>
<ENTRY>interval</ENTRY>
<ENTRY>12 bytes</ENTRY>
<ENTRY><acronym>SQL92</acronym> type</ENTRY>
1998-03-01 09:16:16 +01:00
<ENTRY>equivalent to timespan</ENTRY>
</ROW>
<ROW>
<ENTRY>reltime</ENTRY>
<ENTRY>4 bytes</ENTRY>
<ENTRY>original time interval</ENTRY>
<ENTRY>limited range, low precision</ENTRY>
</ROW>
<ROW>
<ENTRY>time</ENTRY>
<ENTRY>4 bytes</ENTRY>
<ENTRY><acronym>SQL92</acronym> type</ENTRY>
1998-03-01 09:16:16 +01:00
<ENTRY>wide range</ENTRY>
</ROW>
<ROW>
<ENTRY>timespan</ENTRY>
<ENTRY>12 bytes</ENTRY>
<ENTRY>best general time interval</ENTRY>
<ENTRY>wide range, high precision</ENTRY>
</ROW>
<ROW>
<ENTRY>timestamp</ENTRY>
<ENTRY>4 bytes</ENTRY>
<ENTRY><acronym>SQL92</acronym> type</ENTRY>
1998-03-01 09:16:16 +01:00
<ENTRY>limited range</ENTRY>
</ROW>
</TBODY>
</TGROUP>
</TABLE>
1998-10-27 07:14:41 +01:00
<type>timestamp</type> is currently implemented separately from
<type>datetime</type>, although they share input and output routines.
1998-03-01 09:16:16 +01:00
</Para>
<Para>
<TABLE TOCENTRY="1">
<TITLE><ProductName>Postgres</ProductName> Date/Time Ranges</TITLE>
<TITLEABBREV>Ranges</TITLEABBREV>
<TGROUP COLS="4">
<THEAD>
<ROW>
<ENTRY>Date/Time Type</ENTRY>
<ENTRY>Earliest</ENTRY>
<ENTRY>Latest</ENTRY>
<ENTRY>Resolution</ENTRY>
</ROW>
</THEAD>
<TBODY>
<ROW>
<ENTRY>abstime</ENTRY>
<ENTRY>1901-12-14</ENTRY>
<ENTRY>2038-01-19</ENTRY>
<ENTRY>1 sec</ENTRY>
</ROW>
<ROW>
<ENTRY>date</ENTRY>
<ENTRY>4713 BC</ENTRY>
<ENTRY>32767 AD</ENTRY>
1998-03-01 09:16:16 +01:00
<ENTRY>1 day</ENTRY>
</ROW>
<ROW>
<ENTRY>datetime</ENTRY>
<ENTRY>4713 BC</ENTRY>
<ENTRY>1465001 AD</ENTRY>
1998-03-01 09:16:16 +01:00
<ENTRY>1 microsec to 14 digits</ENTRY>
</ROW>
<ROW>
<ENTRY>interval</ENTRY>
<ENTRY>-178000000 years</ENTRY>
<ENTRY>178000000 years</ENTRY>
1998-03-01 09:16:16 +01:00
<ENTRY>1 microsec</ENTRY>
</ROW>
<ROW>
<ENTRY>reltime</ENTRY>
<ENTRY>-68 years</ENTRY>
<ENTRY>+68 years</ENTRY>
<ENTRY>1 sec</ENTRY>
</ROW>
<ROW>
<ENTRY>time</ENTRY>
<ENTRY>00:00:00.00</ENTRY>
<ENTRY>23:59:59.99</ENTRY>
<ENTRY>1 microsec</ENTRY>
</ROW>
<ROW>
<ENTRY>timespan</ENTRY>
<ENTRY>-178000000 years</ENTRY>
<ENTRY>178000000 years</ENTRY>
1998-03-01 09:16:16 +01:00
<ENTRY>1 microsec (14 digits)</ENTRY>
</ROW>
<ROW>
<ENTRY>timestamp</ENTRY>
<ENTRY>1901-12-14</ENTRY>
<ENTRY>2038-01-19</ENTRY>
<ENTRY>1 sec</ENTRY>
</ROW>
</TBODY>
</TGROUP>
</TABLE>
</Para>
<Para>
<ProductName>Postgres</ProductName> endevours to be compatible with
<Acronym>SQL92</Acronym> definitions for typical usage.
The <Acronym>SQL92</Acronym> standard has an odd mix of date and
1998-10-27 07:14:41 +01:00
time types and capabilities. Two obvious problems are:
<itemizedlist>
<listitem>
<para>
Although the <type>date</type> type
does not have an associated time zone, the
1998-10-27 07:14:41 +01:00
<type>time</type> type can or does.
<listitem>
<para>
The default time zone is specified as a constant integer offset
from GMT/UTC.
</itemizedlist>
However, 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.
1998-03-01 09:16:16 +01:00
<Para>
To address these difficulties, <ProductName>Postgres</ProductName>
associates time zones only with date and time
types which contain both date and time,
and 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>
In future releases, the number of date/time types will decrease,
with the current implementation of
<Type>datetime</Type> becoming <Type>timestamp</Type>,
<Type>timespan</Type> becoming <Type>interval</Type>,
and (possibly) <Type>abstime</Type> and <Type>reltime</Type>
being deprecated in favor of <Type>timestamp</Type> and <Type>interval</Type>.
The more arcane features of the date/time definitions from
the <Acronym>SQL92</Acronym> standard are not likely to be pursued.
1998-03-01 09:16:16 +01:00
</Para>
<Sect2>
<Title>Date/Time Styles</Title>
<Para>
Output formats can be set to one of four styles:
ISO-8601, <acronym>SQL</acronym> (Ingres), traditional
1998-03-01 09:16:16 +01:00
Postgres, and German.
<TABLE TOCENTRY="1">
<TITLE><ProductName>Postgres</ProductName> Date 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><acronym>SQL</acronym></ENTRY>
1998-03-01 09:16:16 +01:00
<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 <acronym>SQL</acronym> style has European and non-European (US) variants,
which determines whether month follows day or vica versa.
1998-03-01 09:16:16 +01:00
<TABLE TOCENTRY="1">
<TITLE><ProductName>Postgres</ProductName> Date Order Conventions</TITLE>
<TITLEABBREV>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>Regional convention</ENTRY>
<ENTRY>17/12/1997 15:37:16.00 MET</ENTRY>
</ROW>
<ROW>
<ENTRY>NonEuropean</ENTRY>
<ENTRY>Regional convention</ENTRY>
<ENTRY>12/17/1997 07:37:16.00 PST</ENTRY>
</ROW>
<ROW>
<ENTRY>US</ENTRY>
<ENTRY>Regional convention</ENTRY>
<ENTRY>12/17/1997 07:37:16.00 PST</ENTRY>
</ROW>
</TBODY>
</TGROUP>
</TABLE>
</Para>
<Para>
There are several ways to affect the appearance of date/time types:
<ItemizedList Mark="bullet" Spacing="compact">
<ListItem>
<Para>
The PGDATESTYLE environment variable used by the backend directly
on postmaster startup.
1998-03-01 09:16:16 +01:00
</Para>
</ListItem>
<ListItem>
<Para>
The PGDATESTYLE environment variable used by the frontend libpq
on session startup.
1998-03-01 09:16:16 +01:00
</Para>
</ListItem>
<ListItem>
<Para>
SET DateStyle <Acronym>SQL</Acronym> command.
</Para>
</ListItem>
</ItemizedList>
<Para>
For <ProductName>Postgres</ProductName> v6.4 (and earlier)
the default date/time style is
"non-European traditional Postgres".
In future releases, the default may become ISO-8601, which alleviates
1998-03-01 09:16:16 +01:00
date specification ambiguities and Y2K collation problems.
</Para>
</Sect2>
<Sect2>
<Title>Time Zones</Title>
<Para>
<ProductName>Postgres</ProductName> obtains time zone support
from the underlying operating system.
All dates and times are stored internally in Universal Coordinated Time (UTC),
alternately known as Greenwich Mean Time (GMT).
Times are converted to local time on the database server before being
1998-03-01 09:16:16 +01:00
sent to the client frontend, hence by default are in the server time zone.
<Para>
There are several ways to affect the time zone behavior:
<ItemizedList Mark="bullet" Spacing="compact">
<ListItem>
<Para>
The TZ environment variable used by the backend directly
on postmaster startup 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.
1998-03-01 09:16:16 +01:00
</Para>
</ListItem>
<ListItem>
<Para>
The <Acronym>SQL</Acronym> command <Command>SET TIME ZONE</Command>
sets the time zone for the session.
1998-03-01 09:16:16 +01:00
</Para>
</ListItem>
</ItemizedList>
<Para>
If an invalid time zone is specified,
the time zone becomes GMT (on most systems anyway).
</Para>
</Sect2>
<Sect2>
<Title>Date/Time Input</Title>
<Para>
General-use date and time is input using a wide range of
styles, including ISO-compatible, <acronym>SQL</acronym>-compatible,
traditional <ProductName>Postgres</ProductName>
1998-03-01 09:16:16 +01:00
and other permutations of date and time. In cases where interpretation
can be ambiguous (quite possible with many traditional styles of date
specification) <ProductName>Postgres</ProductName> uses a style setting
to resolve the ambiguity.
1998-03-01 09:16:16 +01:00
</Para>
<Para>
Most date and time types share code for data input. For those types
the input can have any of a wide variety of styles. For numeric date
representations,
European and US conventions can differ, and the proper interpretation
is obtained
1998-03-01 09:16:16 +01:00
by using the
<Command>set datestyle</Command>
command before entering data.
Note that the style setting does not preclude use of various styles for input;
it is
1998-03-01 09:16:16 +01:00
used primarily to determine the output style and to resolve ambiguities.
</Para>
<Para>
The special values `current',
`infinity' and `-infinity' are provided.
`infinity' specifies a time later than any other valid time, and
`-infinity' specifies a time earlier than any other valid time.
`current' indicates that the current time should be
substituted whenever this value appears in a computation.
The strings
`now',
`today',
`yesterday',
`tomorrow',
and `epoch' can be used to specify
time values. `now' means the current transaction time, and differs from
`current' in that the current time is immediately substituted
for it. `epoch' means Jan 1 00:00:00 1970 GMT.
</Para>
<Para>
<TABLE TOCENTRY="1">
<TITLE><ProductName>Postgres</ProductName> Date/Time Special 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>
</Para>
</Sect2>
<Sect2>
<Title>datetime</Title>
<Para>
General-use date and time is input using a wide range of
styles, including ISO-compatible, <acronym>SQL</acronym>-compatible, traditional
1998-03-01 09:16:16 +01:00
<ProductName>Postgres</ProductName> (see section on "absolute time")
and other permutations of date and time. Output styles can be ISO-compatible,
<acronym>SQL</acronym>-compatible, or traditional
<ProductName>Postgres</ProductName>, with the default set to be compatible
1998-03-01 09:16:16 +01:00
with <ProductName>Postgres</ProductName> v6.0.
</Para>
<Para>
<Type>datetime</Type> is specified using the following syntax:
<ProgramListing>
Year-Month-Day [ Hour : Minute : Second ] [AD,BC] [ Timezone ]
YearMonthDay [ Hour : Minute : Second ] [AD,BC] [ Timezone ]
Month Day [ Hour : Minute : Second ] Year [AD,BC] [ Timezone ]
where
Year is 4013 BC, ..., very large
Month is Jan, Feb, ..., Dec or 1, 2, ..., 12
Day is 1, 2, ..., 31
Hour is 00, 02, ..., 23
Minute is 00, 01, ..., 59
Second is 00, 01, ..., 59 (60 for leap second)
Timezone is 3 characters or ISO offset to GMT
</ProgramListing>
<Para>
Valid dates are from Nov 13 00:00:00 4013 BC GMT to far into the future.
Timezones are either three characters (e.g. "GMT" or "PST") or ISO-compatible
offsets to GMT (e.g. "-08" or "-08:00" when in Pacific Standard Time).
Dates are stored internally in Greenwich Mean Time. Input and output routines
translate time to the local time zone of the server.
</Para>
<Sect2>
<Title><Type>timespan</Type></Title>
<Para>
General-use time span is input using a wide range of
syntaxes, including ISO-compatible, <acronym>SQL</acronym>-compatible,
traditional
1998-03-01 09:16:16 +01:00
<ProductName>Postgres</ProductName> (see section on "relative time")
and other permutations of time span. Output formats can be ISO-compatible,
<acronym>SQL</acronym>-compatible, or traditional
<ProductName>Postgres</ProductName>,
with the default set to be <ProductName>Postgres</ProductName>-compatible.
1998-03-01 09:16:16 +01:00
Months and years are a "qualitative" time interval, and are stored separately
from the other "quantitative" time intervals such as day or hour.
For date arithmetic,
the qualitative time units are instantiated in the context of the
relevant date or time.
1998-03-01 09:16:16 +01:00
<Para>
Time span is specified with the following syntax:
<ProgramListing>
Quantity Unit [Quantity Unit...] [Direction]
@ Quantity Unit [Direction]
where
Quantity is ..., `-1', `0', `1', `2', ...
Unit is `second', `minute', `hour', `day', `week', `month', `year',
'decade', 'century', millenium', or abbreviations or plurals of these units.
Direction is `ago'.
</ProgramListing>
</Para>
</Sect2>
<Sect2>
<Title>abstime</Title>
<Para>
Absolute time (<type>abstime</type>) is a limited-range (+/- 68 years) and
limited-precision (1 sec)
1998-03-01 09:16:16 +01:00
date data type. <Type>datetime</Type> may be preferred, since it
covers a larger range with greater precision.
<Para>
Absolute time is specified using the following syntax:
<ProgramListing>
Month Day [ Hour : Minute : Second ] Year [ Timezone ]
where
Month is Jan, Feb, ..., Dec
Day is 1, 2, ..., 31
Hour is 01, 02, ..., 24
Minute is 00, 01, ..., 59
Second is 00, 01, ..., 59
Year is 1901, 1902, ..., 2038
</ProgramListing>
</Para>
<Para>
Valid dates are from Dec 13 20:45:53 1901 GMT to Jan 19 03:14:04
2038 GMT.
<note>
<title>Historical Note</title>
<para>
As of Version 3.0, times are no longer read and written
1998-03-01 09:16:16 +01:00
using Greenwich Mean Time; the input and output routines default to
the local time zone.
</note>
1998-03-01 09:16:16 +01:00
All special values allowed for <Type>datetime</Type> are also
allowed for "absolute time".
1998-03-01 09:16:16 +01:00
</Para>
</Sect2>
<Sect2>
<Title>reltime</Title>
<Para>
Relative time <Type>reltime</Type> is a limited-range (+/- 68 years)
and limited-precision (1 sec) time span data type.
<Type>timespan</Type> should be preferred, since it
covers a larger range with greater precision and, more importantly,
can distinguish between
relative units (months and years) and quantitative units (days, hours, etc).
Instead, reltime
must force months to be exactly 30 days, so time arithmetic does not
always work as expected.
For example, adding one reltime year to abstime today does not
produce today's date one year from
1998-03-01 09:16:16 +01:00
now, but rather a date 360 days from today.
</Para>
<Para>
<Type>reltime</Type> shares input and output routines with the other
time span types.
1998-03-01 09:16:16 +01:00
The section on <Type>timespan</Type> covers this in more detail.
</Para>
</Sect2>
<Sect2>
<Title><Type>timestamp</Type></Title>
<Para>
This is currently a limited-range absolute time which closely resembles the
abstime
data type. It shares the general input parser with the other date/time types.
In future releases this type will absorb the capabilities of the
<Type>datetime</Type> type
and will move toward <acronym>SQL92</acronym> compliance.
1998-03-01 09:16:16 +01:00
</Para>
<Para>
<Type>timestamp</Type> is specified using the same syntax as for
<Type>datetime</Type>.
1998-03-01 09:16:16 +01:00
</Para>
</Sect2>
<Sect2>
<Title><Type>interval</Type></Title>
<Para>
<Type>interval</Type> is an <Acronym>SQL92</Acronym> data type which is
currently mapped to the <Type>timespan</Type>
<ProductName>Postgres</ProductName> data type.
1998-03-01 09:16:16 +01:00
</Para>
</Sect2>
<Sect2>
<Title>tinterval</Title>
<Para>
Time ranges are specified as:
<ProgramListing>
[ 'abstime' 'abstime']
where
abstime is a time in the absolute time format.
</ProgramListing>
Special abstime values such as
`current', `infinity' and `-infinity' can be used.
</Para>
</Sect1>
<Sect1>
<Title>Boolean Type</Title>
<Para>
<ProductName>Postgres</ProductName> supports <Type>bool</Type> as
the <Acronym>SQL3</Acronym> boolean type.
<Type>bool</Type> can have one of only two states: 'true' or 'false'.
A third state, 'unknown', is not
implemented and is not suggested in <Acronym>SQL3</Acronym>;
<Acronym>NULL</Acronym> is an
effective substitute. <Type>bool</Type> can be used in any boolean expression,
and boolean expressions
1998-03-01 09:16:16 +01:00
always evaluate to a result compatible with this type.
<Para>
<Type>bool</Type> uses 4 bytes 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>Output</ENTRY>
<ENTRY>Input</ENTRY>
</ROW>
</THEAD>
<TBODY>
<ROW>
<ENTRY>True</ENTRY>
<ENTRY>'t'</ENTRY>
<ENTRY>TRUE, 't', 'true', 'y', 'yes', '1'</ENTRY>
</ROW>
<ROW>
<ENTRY>False</ENTRY>
<ENTRY>'f'</ENTRY>
<ENTRY>FALSE, 'f', 'false', 'n', 'no', '0'</ENTRY>
</ROW>
</TBODY>
</TGROUP>
</TABLE>
</Para>
</Sect1>
<Sect1>
<Title>Geometric Types</Title>
<Para>
Geometric types represent two-dimensional spatial objects.
The most fundamental type,
1998-03-01 09:16:16 +01:00
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.
1998-03-01 09:16:16 +01:00
</Para>
<Sect2>
<Title>Point</Title>
<Para>
Points are specified using the following syntax:
<ProgramListing>
( x , y )
x , y
where
x is the x-axis coordinate as a floating point number
y is the y-axis coordinate as a floating point number
</ProgramListing>
</Para>
</Sect2>
<Sect2>
<Title>Line Segment</Title>
<Para>
Line segments (lseg) are represented by pairs of points.
</Para>
<Para>
lseg is specified using the following syntax:
<ProgramListing>
( ( x1 , y1 ) , ( x2 , y2 ) )
( x1 , y1 ) , ( x2 , y2 )
x1 , y1 , x2 , y2
where
(x1,y1) and (x2,y2) are the endpoints of the segment
</ProgramListing>
</Para>
</Sect2>
<Sect2>
<Title>Box</Title>
<Para>
Boxes are represented by pairs of points which are opposite
corners of the box.
</Para>
<Para>
box is specified using the following syntax:
<ProgramListing>
( ( x1 , y1 ) , ( x2 , y2 ) )
( x1 , y1 ) , ( x2 , y2 )
x1 , y1 , x2 , y2
where
(x1,y1) and (x2,y2) are opposite corners
</ProgramListing>
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 select either type in a query.
</Para>
<Para>
path is specified using the following syntax:
<ProgramListing>
( ( x1 , y1 ) , ... , ( xn , yn ) )
[ ( x1 , y1 ) , ... , ( xn , yn ) ]
( x1 , y1 ) , ... , ( xn , yn )
( x1 , y1 , ... , xn , yn )
x1 , y1 , ... , xn , yn
where
(x1,y1),...,(xn,yn) are points 1 through n
a leading "[" indicates an open path
a leading "(" indicates a closed path
</ProgramListing>
Paths are output using the first syntax.
Note that <ProductName>Postgres</ProductName> versions prior to
v6.1 used a format for paths which had a single leading parenthesis,
a "closed" flag,
1998-03-01 09:16:16 +01:00
an integer count of the number of points, then the list of points followed by a
closing parenthesis.
The built-in function <Function>upgradepath</Function> is supplied to convert
1998-03-01 09:16:16 +01:00
paths dumped and reloaded from pre-v6.1 databases.
</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.
1998-03-01 09:16:16 +01:00
</Para>
<Para>
polygon is specified using the following syntax:
<ProgramListing>
( ( x1 , y1 ) , ... , ( xn , yn ) )
( x1 , y1 ) , ... , ( xn , yn )
( x1 , y1 , ... , xn , yn )
x1 , y1 , ... , xn , yn
where
(x1,y1),...,(xn,yn) are points 1 through n
</ProgramListing>
Polygons are output using the first syntax.
Note that <ProductName>Postgres</ProductName> versions prior to
v6.1 used a format for polygons which had a single leading parenthesis, the list
of x-axis coordinates, the list of y-axis coordinates,
followed by a closing parenthesis.
1998-03-01 09:16:16 +01:00
The built-in function <Function>upgradepoly</Function> is supplied to convert
polygons dumped and reloaded from pre-v6.1 databases.
</Para>
</Sect2>
<Sect2>
<Title>Circle</Title>
<Para>
Circles are represented by a center point and a radius.
</Para>
<Para>
circle is specified using the following syntax:
<ProgramListing>
< ( x , y ) , r >
( ( x , y ) , r )
( x , y ) , r
x , y , r
where
(x,y) is the center of the circle
r is the radius of the circle
</ProgramListing>
Circles are output using the first syntax.
</Para>
</Sect2>
</Sect1>
1998-10-27 07:14:41 +01:00
<Sect1>
<Title>IP Version 4 Networks and Host Addresses</Title>
<Para>
The <Type>cidr</Type> type stores networks specified
in <acronym>CIDR</acronym> notation.
The <Type>inet</Type> type stores hosts and networks in CIDR notation.
</Para>
<Para>
<TABLE TOCENTRY="1">
<TITLE><ProductName>Postgres</ProductName>IP Version 4 Type</TITLE>
<TITLEABBREV>IPV4</TITLEABBREV>
<TGROUP COLS="4">
<THEAD>
<ROW>
<ENTRY>IPV4 Type</ENTRY>
<ENTRY>Storage</ENTRY>
<ENTRY>Description</ENTRY>
<ENTRY>Range</ENTRY>
</ROW>
</THEAD>
<TBODY>
<ROW>
<ENTRY>cidr</ENTRY>
<ENTRY>variable</ENTRY>
<ENTRY>CIDR networks</ENTRY>
<ENTRY>Valid IPV4 CIDR blocks</ENTRY>
</ROW>
<ROW>
<ENTRY>inet</ENTRY>
<ENTRY>variable</ENTRY>
<ENTRY>nets and hosts</ENTRY>
<ENTRY>Valid IPV4 CIDR blocks</ENTRY>
</ROW>
</TBODY>
</TGROUP>
</TABLE>
</Para>
<Sect2>
<Title><type>inet</type> for IP Networks</Title>
<Para>
The cidr type holds a CIDR network.
The format for specifying networks is "x.x.x.x/y" where "x.x.x.x" is the
network and "/y" is the number of bits in the netmask.
If the "/y" part is left off, it is calculated using assumptions from
the old class system except that it is extended to include at least
all of the octets in the input.
Here are some examples.
<!-- There's a lot of examples here.
-- Take some out if you think there are too many...
-->
<Para>
<TABLE TOCENTRY="1">
<TGROUP COLS="4">
<THEAD>
<ROW>
<ENTRY>Input</ENTRY>
<ENTRY>Output</ENTRY>
</THEAD>
<TBODY>
<ROW>
<ENTRY>select '192.168.1'::cidr</ENTRY>
<ENTRY>192.168.1/24</ENTRY>
</ROW>
<ROW>
<ENTRY>select '192.168'::cidr</ENTRY>
<ENTRY>192.168.0/24</ENTRY>
</ROW>
<ROW>
<ENTRY>select '128.1'::cidr</ENTRY>
<ENTRY>128.1/16</ENTRY>
</ROW>
<ROW>
<ENTRY>select '128':::cidr</ENTRY>
<ENTRY>128.0/16</ENTRY>
</ROW>
<ROW>
<ENTRY>select '128.1.2'::cidr</ENTRY>
<ENTRY>128.1.2/24</ENTRY>
</ROW>
<ROW>
<ENTRY>select '10.1.2'::cidr</ENTRY>
<ENTRY>10.1.2/24</ENTRY>
</ROW>
<ROW>
<ENTRY>select '10.1'::cidr</ENTRY>
<ENTRY>10.1/16</ENTRY>
</ROW>
<ROW>
<ENTRY>select '10'::cidr</ENTRY>
<ENTRY>10/8</ENTRY>
</ROW>
</TBODY>
</TGROUP>
</TABLE>
</Para>
<Sect2>
<Title><type>inet</type> for IP Networks</Title>
<Para>
The inet type is designed to hold, in one field, all of the information
about a host including the CIDR style subnet that it is in.
Note that if you want to store proper CIDR networks, see the cidr type.
The inet type is similar to the cidr type except that the bits in the
host part can be non-zero.
Functions exist to extract the various elements of the field.
</Para>
<Para>
The input format for this function is "x.x.x.x/y" where "x.x.x.x" is
an internet host and y is the number of bits in the netmask.
If the "/y" part is left off, it is treated as "/32."
On output, the "/y" part is not printed if it is /32.
This allows the type to be used as a straight host type by just leaving of
the bits part.
</Sect1>
</chapter>