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 DEFINE TYPE command described elsewhere.
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.
Table 3-1. Postgres Data Types
Postgres Type | SQL92 or SQL3 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 |
float4/8 | float(p) | floating-point number with precision p |
float8 | real, double precision | double-precision floating-point number |
inet | IP version 4 network or host address | |
int2 | smallint | signed two-byte integer |
int4 | int, integer | signed 4-byte integer |
int4 | decimal(p,s) | exact numeric for p <= 9, s = 0 |
int4 | numeric(p,s) | exact numeric for p == 9, s = 0 |
int8 | signed 8-byte integer | |
line | infinite line in 2D plane | |
lseg | line segment in 2D plane | |
money | decimal(9,2) | US-style currency |
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 | |
time | time | time of day |
timespan | interval | general-use time span |
timestamp | timestamp with time zone | date/time |
varchar(n) | character varying(n) | variable-length character string |
Note: 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.
Table 3-2. Postgres Function Constants
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 SQL3 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.
Note that 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.
Note: The original Postgres 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.
Numeric types consist of two- and four-byte integers and four- and eight-byte floating point numbers.
Table 3-3. Postgres Numeric Types
Numeric Type | Storage | Description | Range |
---|---|---|---|
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 |
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 Numerical Operators and Mathematical Functions for more information.
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);
Caution |
The implicit sequence created for the serial type will not be automatically removed when the table 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. |
The int8 type may not be available on all platforms since it relies on compiler support for this.