Data Types
Postgres has a rich set of native data
types available to users.
Users may add new types to Postgres using the
CREATE TYPE command.
shows all general-purpose data types
available to users. Most of the alternative names listed in the
Aliases
column are the names used internally by
Postgres 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 Postgres, such as open and closed
paths, or have several possibilities for formats, such as the date
and time types.
Data Types
Type Name
Aliases
Description
bigint
int8
signed eight-byte integer
bit
fixed-length bit string
bit varying(n)
varbit(n)
variable-length bit string
boolean
bool
logical Boolean (true/false)
box
rectangular box in 2D plane
character(n)
char(n)
fixed-length character string
character varying(n)
varchar(n)
variable-length character string
cidr
IP network address
circle
circle in 2D plane
date
calendar date (year, month, day)
double precision
float8
double precision floating-point number
inet
IP host address
integer
int, int4
signed four-byte integer
interval
general-use time span
line
infinite line in 2D plane
lseg
line segment in 2D plane
macaddr
MAC address
money
US-style currency
numeric(p, s)
decimal(p, s)
exact numeric with selectable precision
oid
object identifier
path
open and closed geometric path in 2D plane
point
geometric point in 2D plane
polygon
closed geometric path in 2D plane
real
float4
single precision floating-point number
smallint
int2
signed two-byte integer
serial
autoincrementing four-byte integer
text
variable-length character string
time [ without time zone ]
time of day
time with time zone
time of day, including time zone
timestamp [ with time zone ]
date and time
Compatibility
The following types (or spellings thereof) are specified by SQL:
bit, bit varying, boolean,
char, character, character
varying, varchar, date,
double precision, integer,
interval, numeric, decimal,
real, smallint, time,
timestamp (both with or without time zone).
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.
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.
Numeric Types
Numeric types consist of two-, four-, and eight-byte integers,
four- and eight-byte
floating point numbers and fixed-precision decimals.
Numeric Types
Type Name
Storage
Description
Range
smallint
2 bytes
Fixed-precision
-32768 to +32767
integer
4 bytes
Usual choice for fixed-precision
-2147483648 to +2147483647
bigint
8 bytes
Very large range fixed-precision
about 18 decimal places
decimal
variable
User-specified precision
no limit
numeric
variable
User-specified precision
no limit
real
4 bytes
Variable-precision
6 decimal places
double precision
8 bytes
Variable-precision
15 decimal places
serial
4 bytes
Identifier or cross-reference
0 to +2147483647
The syntax of constants for the numeric types is described in
. The numeric types have a
full set of corresponding arithmetic operators and
functions. Refer to for more
information.
The bigint type may not be available on all platforms since
it relies on compiler support for eight-byte integers.
The Serial Type
The serial type is a special-case type constructed by
Postgres from other existing components.
It is typically used to create unique identifiers for table entries.
In the current implementation, specifying
CREATE TABLE tablename (colname SERIAL);
is equivalent to specifying:
CREATE SEQUENCE tablename_colname_seq;
CREATE TABLE tablename
(colname integer DEFAULT nextval('tablename_colname_seq');
CREATE UNIQUE INDEX tablename_colname_key on tablename (colname);
The implicit sequence created for the serial type will
not be automatically removed when the
table is dropped.
Implicit sequences supporting the serial are
not automatically dropped when a table containing a serial type
is dropped. So, the following commands executed in order will likely fail:
CREATE TABLE tablename (colname SERIAL);
DROP TABLE tablename;
CREATE TABLE tablename (colname SERIAL);
The sequence will remain in the database until explicitly dropped using
DROP SEQUENCE.
Monetary Type
Deprecated
The money type is deprecated. Use
numeric or decimal instead, in
combination with the to_char function. The
money type may become a locale-aware layer over the
numeric type in a future release.
The money type stores U.S.-style currency with fixed
decimal point representation. If
Postgres is compiled with locale
support then the money type uses locale-specific
output formatting.
Input is accepted in a variety of formats, including integer and
floating point literals, as well as typical
currency formatting, such as '$1,000.00'.
Output is in the latter form.
Monetary Types
Type Name
Storage
Description
Range
money
4 bytes
Fixed-precision
-21474836.48 to +21474836.47
Character Types
SQL defines two primary character types:
character and character varying.
Postgres supports these types, in
addition to the more general text type,
which unlike character varying
does not require an explicit declared upper
limit on the size of the field.
Refer to for information about
the syntax of string literals, and to
for information about available operators and functions.
Character Types
Type Name
Storage
Recommendation
Description
character(n), char(n)
(4+n) bytes
SQL-compatible
Fixed-length blank padded
character varying(n), varchar(n)
(4+n) bytes
SQL-compatible
Variable-length with limit
text
(4+n) bytes
Most flexible
Variable unlimited length
Although the type text is not SQL-compliant, many
other RDBMS packages have it as well.
There are two other fixed-length character types in
Postgres. The name type
exists only 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
NAMEDATALEN. 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
"char" (note the quotes) is different from
char(1) in that it only uses one byte of storage. It
is internally used in the system catalogs as a poor-man's
enumeration type.
Specialty Character Type
Type Name
Storage
Description
"char"
1 byte
Single character internal type
name
32 bytes
Thirty-one character internal type
Date/Time Types
Postgres supports the full set of
SQL date and time types.
Date/Time Types
Type
Description
Storage
Earliest
Latest
Resolution
timestamp
both date and time
8 bytes
4713 BC
AD 1465001
1 microsecond / 14 digits
timestamp [ with time zone ]
date and time with time zone
8 bytes
1903 AD
2037 AD
1 microsecond / 14 digits
interval
for time intervals
12 bytes
-178000000 years
178000000 years
1 microsecond
date
dates only
4 bytes
4713 BC
32767 AD
1 day
time [ without time zone ]
times of day only
4 bytes
00:00:00.00
23:59:59.99
1 microsecond
time with time zone
times of day only
4 bytes
00:00:00.00+12
23:59:59.99-12
1 microsecond
To ensure compatibility to earlier versions of Postgres
we also continue to provide datetime (equivalent to timestamp) and
timespan (equivalent to interval),
however support for these is now restricted to having an
implicit translation to timestamp and
interval.
The types abstime
and reltime are lower precision types which are used internally.
You are discouraged from using any of these types in new
applications and are encouraged to move any old
ones over when appropriate. Any or all of these internal types might disappear in a future release.
Date/Time Input
Date and time input is accepted in almost any reasonable format, including
ISO-8601, SQL-compatible,
traditional Postgres, 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
SET DateStyle TO 'US' or SET DateStyle TO 'NonEuropean'
specifies the variant "month before day", the command
SET DateStyle TO 'European' sets the variant
"day before month". The ISO style
is the default but this default can be changed at compile time or at run time.
See
for the exact parsing rules of date/time input and for the recognized time zones.
Remember that any date or time input needs to be enclosed into
single quotes, like text strings. Refer to for more information.
SQL requires the following syntax
type 'value'
but Postgres is more flexible.
date
The following are possible inputs for the date type.
Date Input
Example
Description
January 8, 1999
Unambiguous
1999-01-08
ISO-8601 format, preferred
1/8/1999
US; read as August 1 in European mode
8/1/1999
European; read as August 1 in US mode
1/18/1999
US; read as January 18 in any mode
19990108
ISO-8601 year, month, day
990108
ISO-8601 year, month, day
1999.008
Year and day of year
99008
Year and day of year
January 8, 99 BC
Year 99 before the Common Era
Month Abbreviations
Month
Abbreviations
April
Apr
August
Aug
December
Dec
February
Feb
January
Jan
July
Jul
June
Jun
March
Mar
November
Nov
October
Oct
September
Sep, Sept
The month May has no explicit abbreviation, for obvious reasons.
Day of the Week Abbreviations
Day
Abbreviation
Sunday
Sun
Monday
Mon
Tuesday
Tue, Tues
Wednesday
Wed, Weds
Thursday
Thu, Thur, Thurs
Friday
Fri
Saturday
Sat
time [ without time zone ]
Per SQL99, this type can be referenced as time and
as time without time zone.
The following are valid time inputs.
Time Input
Example
Description
04:05:06.789
ISO-8601
04:05:06
ISO-8601
04:05
ISO-8601
040506
ISO-8601
04:05 AM
Same as 04:05; AM does not affect value
04:05 PM
Same as 16:05; input hour must be <= 12
z
Same as 00:00:00
zulu
Same as 00:00:00
allballs
Same as 00:00:00
time with time zone
This type is defined by SQL92, but the definition exhibits
fundamental deficiencies that render the type nearly useless. In
most cases, a combination of date,
time, and timestamp
should provide a complete range of date/time functionality
required by any application.
time with time zone accepts all input also legal
for the time type, appended with a legal time zone,
as follows:
Time With Time Zone Input
Example
Description
04:05:06.789-8
ISO-8601
04:05:06-08:00
ISO-8601
04:05-08:00
ISO-8601
040506-08
ISO-8601
Refer to for
more examples of time zones.
timestamp
Valid input for the timestamp type consists of a concatenation
of a date and a time, followed by an optional AD or
BC, followed by an optional time zone. (See below.)
Thus
1999-01-08 04:05:06 -8:00
is a valid timestamp value that is ISO-compliant.
In addition, the wide-spread format
January 8 04:05:06 1999 PST
is supported.
Time Zone Input
Time Zone
Description
PST
Pacific Standard Time
-8:00
ISO-8601 offset for PST
-800
ISO-8601 offset for PST
-8
ISO-8601 offset for PST
interval
intervals can be specified with the following syntax:
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, millennium,
or abbreviations or plurals of these units;
Direction can be ago or
empty.
Special values
The following SQL-compatible functions can be used as date or time
input for the corresponding data type: CURRENT_DATE,
CURRENT_TIME, CURRENT_TIMESTAMP.
Postgres also supports several special constants for
convenience.
Special Date/Time Constants
Constant
Description
current
Current transaction time, deferred
epoch
1970-01-01 00:00:00+00 (Unix system time zero)
infinity
Later than other valid times
-infinity
Earlier than other valid times
invalid
Illegal entry
now
Current transaction time
today
Midnight today
tomorrow
Midnight tomorrow
yesterday
Midnight yesterday
'now' is resolved when the value is inserted, 'current'
is resolved every time the value is retrieved. So you probably want to use 'now'
in most applications. (Of course you really want to use
CURRENT_TIMESTAMP, which is equivalent to 'now'.)
Date/Time Output
Output formats can be set to one of the four styles
ISO-8601, SQL (Ingres), traditional
Postgres, and German, using the SET DateStyle.
The default is the ISO format.
Date/Time Output Styles
Style Specification
Description
Example
'ISO'
ISO-8601 standard
1997-12-17 07:37:16-08
'SQL'
Traditional style
12/17/1997 07:37:16.00 PST
'Postgres'
Original style
Wed Dec 17 07:37:16 1997 PST
'German'
Regional style
17.12.1997 07:37:16.00 PST
The output of the date and time styles is of course
only the date or time part in accordance with the above examples.
The SQL style has European and non-European (US) variants,
which determines whether month follows day or vice versa. (See also above
at Date/Time Input, how this setting affects interpretation of input values.)
Date Order Conventions
Style Specification
Description
Example
European
day/month/year
17/12/1997 15:37:16.00 MET
US
month/day/year
12/17/1997 07:37:16.00 PST
interval output looks like the input format, except that units like
week or century are converted to years and days.
In ISO mode the output looks like
[ Quantity Units [ ... ] ] [ Days ] Hours:Minutes [ ago ]
There are several ways to affect the appearance of date/time types:
The PGDATESTYLE environment variable used by the backend directly
on postmaster start-up.
The PGDATESTYLE environment variable used by the frontend libpq
on session start-up.
SET DATESTYLE SQL command.
Time Zones
Postgres endeavors to be compatible with
SQL92 definitions for typical usage.
However, the SQL92 standard has an odd mix of date and
time types and capabilities. Two obvious problems are:
Although the date type
does not have an associated time zone, the
time type can or does.
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.
The default time zone is specified as a constant integer offset
from GMT/UTC. It is not possible to adapt to daylight savings
time when doing date/time arithmetic across
DST boundaries.
To address these difficulties, we recommend using date/time
types that contain both date and time when using time zones. We
recommend not using the SQL92 type TIME
WITH TIME ZONE (though it is supported by
Postgres for legacy applications and
for compatibility with other RDBMS implementations).
Postgres
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.
Postgres 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).
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.
There are several ways to affect the time zone behavior:
The TZ environment variable is used by the backend directly
on postmaster start-up as the default time zone.
The PGTZ environment variable set at the client used by libpq
to send time zone information to the backend upon connection.
The SQL command SET TIME ZONE
sets the time zone for the session.
The SQL92 qualifier on
timestamp AT TIME ZONE 'zone'
where zone can be specified as a
text time zone (e.g. 'PST') or as an
interval (e.g. INTERVAL '-08:00').
If an invalid time zone is specified,
the time zone becomes GMT (on most systems anyway).
If the compiler option USE_AUSTRALIAN_RULES is set
then EST refers to Australia Eastern Standard Time,
which has an offset of +10:00 hours from UTC.
Internals
Postgres 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.
Date conventions before the 19th century make for interesting reading,
but are not consistent enough to warrant coding into a date/time handler.
Boolean Type
Postgres provides the
SQL99 type boolean.
boolean can have one of only two states:
true
or false
. A third state,
unknown
, is represented by the
SQL NULL state.
Valid literal values for the true
state are:
TRUE
't'
'true'
'y'
'yes'
'1'
For the false
state, the following values can be
used:
FALSE
'f'
'false'
'n'
'no'
'0'
Using the key words TRUE and
FALSE is preferred (and
SQL-compliant).
Using the boolean type
CREATE TABLE test1 (a boolean, b text);
INSERT INTO test1 VALUES (TRUE, 'sic est');
INSERT INTO test1 VALUES (FALSE, 'non est');
SELECT * FROM test1;
a | b
---+---------
t | sic est
f | non est
SELECT * FROM test1 WHERE a;
a | b
---+---------
t | sic est
shows that
boolean values are output using the letters
t and f.
Values of the boolean type cannot be cast directly
to other types (e.g., CAST
(boolval AS integer) does
not work). This can be accomplished using the
CASE expression: CASE WHEN
boolval THEN 'value if true' ELSE
'value if false' END. See also .
boolean uses 1 byte of storage.
Geometric Types
Geometric types represent two-dimensional spatial objects.
The most fundamental type,
the point, forms the basis for all of the other types.
Geometric Types
Geometric Type
Storage
Representation
Description
point
16 bytes
(x,y)
Point in space
line
32 bytes
((x1,y1),(x2,y2))
Infinite line
lseg
32 bytes
((x1,y1),(x2,y2))
Finite line segment
box
32 bytes
((x1,y1),(x2,y2))
Rectangular box
path
4+32n bytes
((x1,y1),...)
Closed path (similar to polygon)
path
4+32n bytes
[(x1,y1),...]
Open path
polygon
4+32n bytes
((x1,y1),...)
Polygon (similar to closed path)
circle
24 bytes
<(x,y),r>
Circle (center and radius)
A rich set of functions and operators is available to perform various geometric
operations such as scaling, translation, rotation, and determining
intersections.
Point
Points are the fundamental two-dimensional building block for geometric types.
point is specified using the following syntax:
( x , y )
x , y
where the arguments are
x
The x-axis coordinate as a floating point number.
y
The y-axis coordinate as a floating point number.
Line Segment
Line segments (lseg) are represented by pairs of points.
lseg is specified using the following syntax:
( ( x1 , y1 ) , ( x2 , y2 ) )
( x1 , y1 ) , ( x2 , y2 )
x1 , y1 , x2 , y2
where the arguments are
(x1,y1)
(x2,y2)
The end points of the line segment.
Box
Boxes are represented by pairs of points that are opposite
corners of the box.
box is specified using the following syntax:
( ( x1 , y1 ) , ( x2 , y2 ) )
( x1 , y1 ) , ( x2 , y2 )
x1 , y1 , x2 , y2
where the arguments are
(x1,y1)
(x2,y2)
Opposite corners of the box.
Boxes are output using the first syntax.
The corners are reordered on input to store
the upper right corner, then the lower left corner.
Other corners of the box can be entered, but the lower
left and upper right corners are determined from the input and stored.
Path
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
popen(p)
and
pclose(p)
are supplied to force a path to be open or closed, and functions
isopen(p)
and
isclosed(p)
are supplied to test for either type in a query.
path is specified using the following syntax:
( ( x1 , y1 ) , ... , ( xn , yn ) )
[ ( x1 , y1 ) , ... , ( xn , yn ) ]
( x1 , y1 ) , ... , ( xn , yn )
( x1 , y1 , ... , xn , yn )
x1 , y1 , ... , xn , yn
where the arguments are
(x,y)
End points of the line segments comprising the path.
A leading square bracket ("[") indicates an open path, while
a leading parenthesis ("(") indicates a closed path.
Paths are output using the first syntax.
Polygon
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.
polygon is specified using the following syntax:
( ( x1 , y1 ) , ... , ( xn , yn ) )
( x1 , y1 ) , ... , ( xn , yn )
( x1 , y1 , ... , xn , yn )
x1 , y1 , ... , xn , yn
where the arguments are
(x,y)
End points of the line segments comprising the boundary of the
polygon.
Polygons are output using the first syntax.
Circle
Circles are represented by a center point and a radius.
circle is specified using the following syntax:
< ( x , y ) , r >
( ( x , y ) , r )
( x , y ) , r
x , y , r
where the arguments are
(x,y)
Center of the circle.
r
Radius of the circle.
Circles are output using the first syntax.
Network Address Data Types
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.
Network Address Data Types
Name
Storage
Description
Range
cidr
12 bytes
IP networks
valid IPv4 networks
inet
12 bytes
IP hosts and networks
valid IPv4 hosts or networks
macaddr
6 bytes
MAC addresses
customary formats
IP v6 is not supported, yet.
inet
The inet 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
cidr type rather than inet.
The input format for this type is x.x.x.x/y where x.x.x.x is an IP address and
y is the number of
bits in the netmask. If the /y part is left off, then the
netmask is 32, and the value represents just a single host.
On display, the /y
portion is suppressed if the netmask is 32.
cidr>
The cidr type holds an IP network specification.
Input and output formats follow Classless Internet Domain Routing
conventions.
The format for
specifying classless 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
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.
Here are some examples:
cidr> Type Input Examples
CIDR Input
CIDR Displayed
abbrev(CIDR)
192.168.100.128/25
192.168.100.128/25
192.168.100.128/25
192.168/24
192.168.0.0/24
192.168.0/24
192.168/25
192.168.0.0/25
192.168.0.0/25
192.168.1
192.168.1.0/24
192.168.1/24
192.168
192.168.0.0/24
192.168.0/24
128.1
128.1.0.0/16
128.1/16
128
128.0.0.0/16
128.0/16
128.1.2
128.1.2.0/24
128.1.2/24
10.1.2
10.1.2.0/24
10.1.2/24
10.1
10.1.0.0/16
10.1/16
10
10.0.0.0/8
10/8
inet vs cidr
The essential difference between inet and cidr
data types is that inet accepts values with nonzero bits to
the right of the netmask, whereas cidr does not.
If you do not like the output format for inet or
cidr values, try the host>(),
text>(), and abbrev>() functions.
macaddr>>
The 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 '08002b:010203'>,
'08002b-010203'>, '0800.2b01.0203'>,
'08-00-2b-01-02-03'>, and
'08:00:2b:01:02:03'>, which would all specify the same
address. Upper and lower case is accepted for the digits
a> through f>. Output is always in the
latter of the given forms.
The directory contrib/mac
in the Postgres source distribution
contains tools that can be used to map MAC addresses to hardware
manufacturer names.
Bit String Types
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:
BIT(x) and BIT
VARYING(x); the
x specifies the maximum length.
BIT type data is automatically padded with 0's on the
right to the maximum length, BIT VARYING is of
variable length. BIT without length is equivalent
to BIT(1), BIT VARYING means
unlimited length. Input data that is longer than the allowed
length will be truncated. Refer to for information about the syntax
of bit string constants. Bit-logical operators and string
manipulation functions are available; see .
Some examples:
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;