Data Types Describes the built-in data types available in Postgres. Postgres has a rich set of native data types available to users. Users may add new types to Postgres using the CREATE TYPE command. In the context of data types, the following sections will discuss SQL standards compliance, porting issues, and usage. Some Postgres types correspond directly to SQL92-compatible types. In other cases, data types defined by SQL92 syntax are mapped directly into native Postgres types. 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. <productname>Postgres</productname> Data TypesData Types Postgres Type SQL92 or SQL99 Type Description bool boolean logical boolean (true/false) box rectangular box in 2D plane char(n) character(n) fixed-length character string cidr IP version 4 network or host address circle circle in 2D plane date date calendar date without time of day decimal decimal(p,s) exact numeric with selectable precision float4 float(p), p < 7 floating-point number with precision p float8 float(p), 7 <= p < 16 floating-point number with precision p inet IP version 4 network or host address int2 smallint signed two-byte integer int4 int, integer signed 4-byte integer int8 signed 8-byte integer interval interval general-use time span line infinite line in 2D plane lseg line segment in 2D plane money decimal(9,2) US-style currency numeric numeric(p,s) exact numeric with selectable precision path open and closed geometric path in 2D plane point geometric point in 2D plane polygon closed geometric path in 2D plane serial unique id for indexing and cross-reference text variable-length character string time time [ without time zone ] time of day timetz time with time zone time of day, including time zone timestamp timestamp [ with time zone ] date/time varchar(n) character varying(n) variable-length character string
The cidr and inet 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. <productname>Postgres</productname> Function ConstantsConstants Postgres Function SQL92 Constant Description getpgusername() current_user user name in current session date('now') current_date date of current transaction time('now') current_time time of current transaction timestamp('now') current_timestamp date and time of current transaction
Postgres has features at the forefront of ORDBMS development. In addition to SQL99 conformance, substantial portions of SQL92 are also supported. Although we strive for SQL92 compliance, there are some aspects of the standard which are ill considered and which should not live through subsequent standards. Postgres 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. 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. 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. Numeric Types Numeric types consist of two-, four-, and eight-byte integers, four- and eight-byte floating point numbers and fixed-precision decimals. <productname>Postgres</productname> Numeric TypesNumerics Numeric Type Storage Description Range decimal variable User-specified precision no limit float4 4 bytes Variable-precision 6 decimal places float8 8 bytes Variable-precision 15 decimal places int2 2 bytes Fixed-precision -32768 to +32767 int4 4 bytes Usual choice for fixed-precision -2147483648 to +2147483647 int8 8 bytes Very large range fixed-precision ~18 decimal places numeric variable User-specified precision no limit serial 4 bytes Identifer or cross-reference 0 to +2147483647
The numeric types have a full set of corresponding arithmetic operators and functions. Refer to and for more information. The int8 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 INT4 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 Obsolete Type The money is now deprecated. Use numeric or decimal instead. The money type may become a locale-aware layer over the numeric type in a future release. The money type supports US-style currency with fixed decimal point representation. If Postgres is compiled with USE_LOCALE then the money type should use the monetary conventions defined for locale(7). <productname>Postgres</productname> Monetary TypesMoney Monetary Type Storage Description Range money 4 bytes Fixed-precision -21474836.48 to +21474836.47
numeric will replace the money type, and should be preferred.
Character Types SQL92 defines two primary character types: char and varchar. Postgres supports these types, in addition to the more general text type, which unlike varchar does not require an explicit declared upper limit on the size of the field. <productname>Postgres</productname> Character TypesCharacters Character Type Storage Recommendation Description "char" 1 byte SQL92-compatible Single character char(n) (4+n) bytes SQL92-compatible Fixed-length blank padded text (4+x) bytes Best choice Variable-length varchar(n) (4+x) bytes SQL92-compatible Variable-length with limit
There is one other fixed-length character type in Postgres. The name type only has one purpose and that is for storage of internal catalog names. It is not intended for use by the general user. Its length is currently defined as 32 bytes (31 characters plus terminator) but should be reference using 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. <productname>Postgres</productname> Specialty Character TypeSpecialty Characters Character Type Storage Description name 32 bytes Thirty-one character internal type
Date/Time Types Postgres supports the full set of SQL date and time types. <productname>Postgres</productname> Date/Time TypesDate/Time Type Description Storage Earliest Latest Resolution timestamp both date and time 8 bytes 4713 BC AD 1465001 1 microsec / 14 digits timestamp [ with time zone ] date and time with time zone 8 bytes 1903 AD 2037 AD 1 microsec / 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. date The following are possible inputs for the date type. <productname>Postgres</productname> Date InputDate Inputs 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
<productname>Postgres</productname> Month AbbreviationsMonth 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.
<productname>Postgres</productname> Day of Week AbbreviationsDay of 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. <productname>Postgres</productname> Time InputTime Inputs 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 which renders 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: <productname>Postgres</productname> Time With Time Zone InputTime With Time Zone Inputs 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, which is ISO-compliant. In addition, the wide-spread format January 8 04:05:06 1999 PST is supported. <productname>Postgres</productname> Time Zone InputTime Zone Inputs 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 datatype: CURRENT_DATE, CURRENT_TIME, CURRENT_TIMESTAMP. Postgres also supports several special constants for convenience. <productname>Postgres</productname> Special Date/Time ConstantsConstants 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 everytime 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. <productname>Postgres</productname> Date/Time Output StylesStyles 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 vica versa. (See also above at Date/Time Input, how this setting affects interpretation of input values.) <productname>Postgres</productname> Date Order ConventionsDate Order 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 startup. The PGDATESTYLE environment variable used by the frontend libpq on session startup. 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. The default time zone is specified as a constant integer offset from GMT/UTC. 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. To address these difficulties, Postgres 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. 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 Universal UTC, alternately 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 used by the backend directly on postmaster startup 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. 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 Std 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 consistant enough to warrant coding into a date/time handler.
Boolean Type Postgres supports bool as the SQL99 boolean type. bool can have one of only two states: 'true' or 'false'. A third state, 'unknown', is not implemented and is not suggested in SQL99; NULL is an effective substitute. bool can be used in any boolean expression, and boolean expressions always evaluate to a result compatible with this type. bool uses 1 byte of storage. <productname>Postgres</productname> Boolean TypeBooleans State Output Input True 't' TRUE, 't', 'true', 'y', 'yes', '1' False 'f' FALSE, 'f', 'false', 'n', 'no', '0'
Geometric Types Geometric types represent two-dimensional spatial objects. The most fundamental type, the point, forms the basis for all of the other types. <productname>Postgres</productname> Geometric TypesGeometrics 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 endpoints of the line segment. Box Boxes are represented by pairs of points which 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 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. 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) Endpoints 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) Endpoints 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.
IP Version 4 Networks and Host Addresses The cidr type stores networks specified in CIDR (Classless Inter-Domain Routing) notation. The inet type stores hosts and networks in CIDR notation using a simple variation in representation to represent simple host TCP/IP addresses. <productname>Postgres</productname>IP Version 4 TypesIPV4 IPV4 Type Storage Description Range cidr variable CIDR networks Valid IPV4 CIDR blocks inet variable nets and hosts Valid IPV4 CIDR blocks
CIDR The cidr type holds a CIDR network. 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 omitted, it is calculated using assumptions from the older classfull naming system except that it is extended to include at least all of the octets in the input. Here are some examples: <productname>Postgres</productname>IP Types Examples CIDR Input CIDR Displayed 192.168.1 192.168.1/24 192.168 192.168.0/24 128.1 128.1/16 128 128.0/16 128.1.2 128.1.2/24 10.1.2 10.1.2/24 10.1 10.1/16 10 10/8
<type>inet</type> 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, you should use 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. 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 off the bits part.