Data Types data types types data types PostgreSQL has a rich set of native data types available to users. Users may add new types to PostgreSQL using the CREATE TYPE command. shows all general-purpose data types included in the standard distribution. Most of the alternative names listed in the Aliases column are the names used internally by PostgreSQL for historical reasons. In addition, some internally used or deprecated types are available, but they are not listed here. Data Types Type Name Aliases Description bigint int8 signed eight-byte integer bigserial serial8 autoincrementing 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 bytea binary data 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(p) 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 serial4 autoincrementing four-byte integer text variable-length character string time [ (p) ] [ without time zone ] time of day time [ (p) ] with time zone timetz time of day, including time zone timestamp [ (p) ] without time zone timestamp date and time timestamp [ (p) ] [ with time zone ] timestamptz date and time, including time zone
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). Each data type has an external representation determined by its input and output functions. Many of the built-in types have obvious external formats. However, several types are either unique to PostgreSQL, such as open and closed paths, or have several possibilities for formats, such as the date and time types. 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 input and output functions are not invertible. That is, the result of an output function may lose precision when compared to the original input. 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. Numeric Types data types numeric integer smallint bigint int4 integer int2 smallint int8 bigint numeric (data type) decimal numeric real double precision float4 real float8 double precision floating point 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 size 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 -9223372036854775808 to 9223372036854775807 decimal variable user-specified precision, exact no limit numeric variable user-specified precision, exact no limit real 4 bytes variable-precision, inexact 6 decimal digits precision double precision 8 bytes variable-precision, inexact 15 decimal digits precision serial 4 bytes autoincrementing integer 1 to 2147483647 bigserial 8 bytes autoincrementing integer 1 to 9223372036854775807
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 following sections describe the types in detail. The Integer Types The types smallint, integer, bigint store whole numbers, that is, numbers without fractional components, of various ranges. Attempts to store values outside of the allowed range will result in an error. The type integer is the usual choice, as it offers the best balance between range, storage size, and performance. The smallint type is generally only used if disk space is at a premium. The bigint type should only be used if the integer range is not sufficient, because the latter is definitely faster. The bigint type may not function correctly on all platforms, since it relies on compiler support for eight-byte integers. On a machine without such support, bigint acts the same as integer (but still takes up eight bytes of storage). However, we are not aware of any reasonable platform where this is actually the case. SQL only specifies the integer types integer (or int) and smallint. The type bigint, and the type names int2, int4, and int8 are extensions, which are shared with various other RDBMS products. If you have a column of type smallint or bigint with an index, you may encounter problems getting the system to use that index. For instance, a clause of the form ... WHERE smallint_column = 42 will not use an index, because the system assigns type integer to the constant 42, and PostgreSQL currently cannot use an index when two different data types are involved. A workaround is to single-quote the constant, thus: ... WHERE smallint_column = '42' This will cause the system to delay type resolution and will assign the right type to the constant. Arbitrary Precision Numbers The type numeric can store numbers of practically unlimited size and precision, while being able to store all numbers and carry out all calculations exactly. It is especially recommended for storing monetary amounts and other quantities where exactness is required. However, the numeric type is very slow compared to the floating-point types described in the next section. In what follows we use these terms: The scale of a numeric is the count of decimal digits in the fractional part, to the right of the decimal point. The precision of a numeric is the total count of significant digits in the whole number, that is, the number of digits to both sides of the decimal point. So the number 23.5141 has a precision of 6 and a scale of 4. Integers can be considered to have a scale of zero. Both the precision and the scale of the numeric type can be configured. To declare a column of type numeric use the syntax NUMERIC(precision, scale) The precision must be positive, the scale zero or positive. Alternatively, NUMERIC(precision) selects a scale of 0. Specifying NUMERIC without any precision or scale creates a column in which numeric values of any precision and scale can be stored, up to the implementation limit on precision. A column of this kind will not coerce input values to any particular scale, whereas numeric columns with a declared scale will coerce input values to that scale. (The SQL standard requires a default scale of 0, i.e., coercion to integer accuracy. We find this a bit useless. If you're concerned about portability, always specify the precision and scale explicitly.) If the precision or scale of a value is greater than the declared precision or scale of a column, the system will attempt to round the value. If the value cannot be rounded so as to satisfy the declared limits, an error is raised. The types decimal and numeric are equivalent. Both types are part of the SQL standard. Floating-Point Types The data types real and double precision are inexact, variable-precision numeric types. In practice, these types are usually implementations of IEEE 754 binary floating point (single and double precision, respectively), to the extent that the underlying processor, operating system, and compiler support it. Inexact means that some values cannot be converted exactly to the internal format and are stored as approximations, so that storing and printing back out a value may show slight discrepancies. Managing these errors and how they propagate through calculations is the subject of an entire branch of mathematics and computer science and will not be discussed further here, except for the following points: If you require exact storage and calculations (such as for monetary amounts), use the numeric type instead. If you want to do complicated calculations with these types for anything important, especially if you rely on certain behavior in boundary cases (infinity, underflow), you should evaluate the implementation carefully. Comparing two floating-point values for equality may or may not work as expected. Normally, the real type has a range of at least -1E+37 to +1E+37 with a precision of at least 6 decimal digits. The double precision type normally has a range of around -1E+308 to +1E+308 with a precision of at least 15 digits. Values that are too large or too small will cause an error. Rounding may take place if the precision of an input number is too high. Numbers too close to zero that are not representable as distinct from zero will cause an underflow error. The Serial Types serial bigserial serial4 serial8 auto-increment serial sequences and serial type The serial data types are not truly types, but are a notational convenience for setting up unique identifier columns in tables. 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') UNIQUE NOT NULL ); Thus, we have created an integer column and arranged for its default values to be assigned from a sequence generator. UNIQUE and NOT NULL constraints are applied to ensure that explicitly-inserted values will never be duplicates, either. The type names serial and serial4 are equivalent: both create integer columns. The type names bigserial and serial8 work just the same way, except that they create a bigint column. bigserial should be used if you anticipate use of more than 231 identifiers over the lifetime of the table. Implicit sequences supporting the serial types 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. (This annoyance will probably be changed in some future release.)
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 PostgreSQL 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 character strings data types strings character strings text character strings Character Types Type name Description character(n), char(n) Fixed-length blank padded character varying(n), varchar(n) Variable-length with limit text Variable unlimited length
SQL defines two primary character types: character(n) and character varying(n), where n is a positive integer. Both of these types can store strings up to n characters in length. An attempt to store a longer string into a column of these types will result in an error, unless the excess characters are all spaces, in which case the string will be truncated to the maximum length. (This somewhat bizarre exception is required by the SQL standard.) If the string to be stored is shorter than the declared length, values of type character will be space-padded; values of type character varying will simply store the shorter string. Prior to PostgreSQL 7.2, strings that were too long were silently truncated, no error was raised. The notations char(n) and varchar(n) are aliases for character(n) and character varying(n), respectively. character without length specifier is equivalent to character(1); if character varying is used without length specifier, the type accepts strings of any size. The latter is a PostgreSQL extension. In addition, PostgreSQL supports the more general text type, which stores strings of any length. Unlike character varying, text does not require an explicit declared upper limit on the size of the string. Although the type text is not in the SQL standard, many other RDBMS packages have it as well. The storage requirement for data of these types is 4 bytes plus the actual string, and in case of character plus the padding. Long strings will be compressed by the system automatically, so the physical requirement on disk may be less. In any case, the longest possible character string that can be stored is about 1 GB. (The maximum value that will be allowed for n in the data type declaration is less than that. It wouldn't be very useful to change this because with multibyte character encodings the number of characters and bytes can be quite different anyway. If you desire to store long strings with no specific upper limit, use text or character varying without a length specifier, rather than making up an arbitrary length limit.) There are no performance differences between these three types, apart from the increased storage size when using the blank-padded type. Refer to for information about the syntax of string literals, and to for information about available operators and functions. Using the character types CREATE TABLE test1 (a character(4)); INSERT INTO test1 VALUES ('ok'); SELECT a, char_length(a) FROM test1; -- a | char_length ------+------------- ok | 4 CREATE TABLE test2 (b varchar(5)); INSERT INTO test2 VALUES ('ok'); INSERT INTO test2 VALUES ('good '); INSERT INTO test2 VALUES ('too long'); ERROR: value too long for type character varying(5) SELECT b, char_length(b) FROM test2; b | char_length -------+------------- ok | 2 good | 5 The char_length function is discussed in . There are two other fixed-length character types in PostgreSQL. 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 usable 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
Binary Strings The bytea data type allows storage of binary strings. Binary String Types Type Name Storage Description bytea 4 bytes plus the actual binary string Variable (not specifically limited) length binary string
A binary string is a sequence of octets that does not have either a character set or collation associated with it. Bytea specifically allows storing octets of zero value and other non-printable octets. Octets of certain values must be escaped (but all octet values may be escaped) when used as part of a string literal in an SQL statement. In general, to escape an octet, it is converted into the three-digit octal number equivalent of its decimal octet value, and preceded by two backslashes. Some octet values have alternate escape sequences, as shown in . <acronym>SQL</acronym> Literal Escaped Octets Decimal Octet Value Description Input Escaped Representation Example Printed Result 0 zero octet '\\000' select '\\000'::bytea; \000 39 single quote '\\'' or '\\047' select '\''::bytea; ' 92 backslash '\\\\' or '\\134' select '\\\\'::bytea; \\
Note that the result in each of the examples above was exactly one octet in length, even though the output representation of the zero octet and backslash are more than one character. Bytea output octets are also escaped. In general, each non-printable octet decimal value is converted into its equivalent three digit octal value, and preceded by one backslash. Most printable octets are represented by their standard representation in the client character set. The octet with decimal value 92 (backslash) has a special alternate output representation. Details are in . <acronym>SQL</acronym> Output Escaped Octets Decimal Octet Value Description Output Escaped Representation Example Printed Result 92 backslash \\ select '\\134'::bytea; \\ 0 to 31 and 127 to 255 non-printable octets \### (octal value) select '\\001'::bytea; \001 32 to 126 printable octets ASCII representation select '\\176'::bytea; ~
SQL string literals (input strings) must be preceded with two backslashes due to the fact that they must pass through two parsers in the PostgreSQL backend. The first backslash is interpreted as an escape character by the string-literal parser, and therefore is consumed, leaving the octets that follow. The remaining backslash is recognized by the bytea input function as the prefix of a three digit octal value. For example, a string literal passed to the backend as '\\001' becomes '\001' after passing through the string-literal parser. The '\001' is then sent to the bytea input function, where it is converted to a single octet with a decimal value of 1. For a similar reason, a backslash must be input as '\\\\' (or '\\134'). The first and third backslashes are interpreted as escape characters by the string-literal parser, and therefore are consumed, leaving two backslashes in the string passed to the bytea input function, which interprets them as representing a single backslash. For example, a string literal passed to the backend as '\\\\' becomes '\\' after passing through the string-literal parser. The '\\' is then sent to the bytea input function, where it is converted to a single octet with a decimal value of 92. A single quote is a bit different in that it must be input as '\'' (or '\\134'), not as '\\''. This is because, while the literal parser interprets the single quote as a special character, and will consume the single backslash, the bytea input function does not recognize a single quote as a special octet. Therefore a string literal passed to the backend as '\'' becomes ''' after passing through the string-literal parser. The ''' is then sent to the bytea input function, where it is retains its single octet decimal value of 39. Depending on the front end to PostgreSQL you use, you may have additional work to do in terms of escaping and unescaping bytea strings. For example, you may also have to escape line feeds and carriage returns if your interface automatically translates these. Or you may have to double up on backslashes if the parser for your language or choice also treats them as an escape character. Bytea provides most of the functionality of the binary string type per SQL99 section 4.3. A comparison of SQL99 Binary Strings and PostgreSQL bytea is presented in . Comparison of SQL99 Binary String and PostgreSQL <type>BYTEA</type> types SQL99 BYTEA Name of data type BINARY LARGE OBJECT or BLOB Name of data type BYTEA Sequence of octets that does not have either a character set or collation associated with it. same Described by a binary data type descriptor containing the name of the data type and the maximum length in octets Described by a binary data type descriptor containing the name of the data type with no specific maximum length All binary strings are mutually comparable in accordance with the rules of comparison predicates. same Binary string values can only be compared for equality. Binary string values can be compared for equality, greater than, greater than or equal, less than, less than or equal Operators operating on and returning binary strings include concatenation, substring, overlay, and trim Operators operating on and returning binary strings include concatenation, substring, and trim. The leading and trailing arguments for trim are not yet implemented. Other operators involving binary strings include length, position, and the like predicate same A binary string literal is comprised of an even number of hexadecimal digits, in single quotes, preceded by X, e.g. X'1a43fe' A binary string literal is comprised of octets escaped according to the rules shown in
Date/Time Types PostgreSQL supports the full set of SQL date and time types. Date/Time Types Type Description Storage Earliest Latest Resolution timestamp [ (p) ] without time zone both date and time 8 bytes 4713 BC AD 1465001 1 microsecond / 14 digits timestamp [ (p) ] [ with time zone ] both date and time 8 bytes 4713 BC AD 1465001 1 microsecond / 14 digits interval [ (p) ] for time intervals 12 bytes -178000000 years 178000000 years 1 microsecond date dates only 4 bytes 4713 BC 32767 AD 1 day time [ (p) ] [ without time zone ] times of day only 8 bytes 00:00:00.00 23:59:59.99 1 microsecond time [ (p) ] with time zone times of day only 12 bytes 00:00:00.00+12 23:59:59.99-12 1 microsecond
time, timestamp, and interval accept an optional precision value p which specifies the number of fractional digits retained in the seconds field. By default, there is no explicit bound on precision. The effective limit of precision is determined by the underlying double precision floating-point number used to store values (in seconds for interval and in seconds since 2000-01-01 for timestamp). The useful range of p is from 0 to about 6 for timestamp, but may be more for interval. The system will accept p ranging from 0 to 13. Time zones, and time-zone conventions, are influenced by political decisions, not just earth geometry. Time zones around the world became somewhat standardized during the 1900's, but continue to be prone to arbitrary changes. PostgreSQL uses your operating system's underlying features to provide output time-zone support, and these systems usually contain information for only the time period 1902 through 2038 (corresponding to the full range of conventional Unix system time). timestamp with time zone and time with time zone will use time zone information only within that year range, and assume that times outside that range are in UTC. To ensure an upgrade path from versions of PostgreSQL earlier than 7.0, we recognize datetime (equivalent to timestamp) and timespan (equivalent to interval). These types are now restricted to having an implicit translation to timestamp and interval, and support for these will be removed in the next release of PostgreSQL (likely named 7.3). 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 PostgreSQL, and others. For some formats, ordering of month and day in date input can be ambiguous and there is support for specifying the expected ordering of these fields. 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. PostgreSQL is more flexible in handling date/time than the SQL standard requires. See for the exact parsing rules of date/time input and for the recognized text fields including months, days of the week, and time zones. Remember that any date or time literal input needs to be enclosed in single quotes, like text strings. Refer to for more information. SQL9x requires the following syntax type [ (p) ] 'value' where p in the optional precision specification is an integer corresponding to the number of fractional digits in the seconds field. Precision can be specified for time, timestamp, and interval types. <type>date</type> date data type The following are some possible inputs for the date type. Date Input Example Description January 8, 1999 Unambiguous 1999-01-08 ISO-8601 format, preferred 1/8/1999 U.S.; read as August 1 in European mode 8/1/1999 European; read as August 1 in U.S. mode 1/18/1999 U.S.; 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 J2451187 Julian day January 8, 99 BC Year 99 before the Common Era
<type>time [ ( <replaceable>p</replaceable> ) ] [ without time zone ]</type> time data type time without time zone time Per SQL99, this type can be specified as time or as time without time zone. The optional precision p should be between 0 and 13, and defaults to the precision of the input time literal. 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 allballs Same as 00:00:00
<type>time [ ( <replaceable>precision</replaceable> ) ] with time zone</type> time with time zone data type time data type This type is defined by SQL92, but the definition exhibits properties which lead to questionable usefulness. In most cases, a combination of date, time, timestamp without time zone and timestamp with time zone should provide a complete range of date/time functionality required by any application. The optional precision p should be between 0 and 13, and defaults to the precision of the input time literal. 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.
<type>timestamp [ (<replaceable>precision</replaceable>) ] without time zone</type> timestamp without time zone data type Valid input for the timestamp [ (p) ] without time zone 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 is a valid timestamp without time zone value that is ISO-compliant. In addition, the wide-spread format January 8 04:05:06 1999 PST is supported. The optional precision p should be between 0 and 13, and defaults to the precision of the input timestamp literal. For timestamp without time zone, any explicit time zone specified in the input is silently swallowed. That is, the resulting date/time value is derived from the explicit date/time fields in the input value, and is not adjusted for time zone. <type>timestamp [ (<replaceable>precision</replaceable>) ] with time zone</type> timestamp data type 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. The optional precision p should be between 0 and 13, and defaults to the precision of the input timestamp literal. 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
<type>interval [ ( <replaceable>precision</replaceable> ) ]</type> interval interval values can be written with the following syntax: Quantity Unit [Quantity Unit...] [Direction] @ Quantity Unit [Quantity Unit...] [Direction] where: Quantity is a number (possibly signed), 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. The at sign (@) is optional noise. The amounts of different units are implicitly added up with appropriate sign accounting. Quantities of days, hours, minutes, and seconds can be specified without explicit unit markings. For example, '1 12:59:10' is read the same as '1 day 12 hours 59 min 10 sec'. The optional precision p should be between 0 and 13, and defaults to the precision of the input literal. Special values time constants date constants The following SQL-compatible functions can be used as date or time input for the corresponding data type: CURRENT_DATE, CURRENT_TIME, CURRENT_TIMESTAMP. The latter two accept an optional precision specification. PostgreSQL also supports several special constants for convenience. Special Date/Time Constants Constant Description 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 zulu, allballs, z 00:00:00.00 GMT
'now' is evaluated when the value is first interpreted.
As of PostgreSQL version 7.2, 'current' is no longer supported as a date/time constant. Previously, 'current' was stored as a special value, and evaluated to 'now' only when used in an expression or type conversion.
Date/Time Output date output format Formatting time output format Formatting Output formats can be set to one of the four styles ISO 8601, SQL (Ingres), traditional PostgreSQL, 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 'PostgreSQL' 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 (U.S.) variants, which determines whether month follows day or vice versa. (See also for 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 time zones PostgreSQL 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. 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-saving time boundaries. The default time zone is specified as a constant integer offset from GMT/UTC. It is not possible to adapt to daylight-saving 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 PostgreSQL for legacy applications and for compatibility with other RDBMS implementations). PostgreSQL assumes your local time zone 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-saving time and other expected behavior. PostgreSQL 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, if set at the client, is used by libpq to send a SET TIME ZONE command 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 runtime option AUSTRALIAN_TIMEZONES is set then CST and EST refer to Australian time zones, not American ones. Internals PostgreSQL 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 Boolean data type true false PostgreSQL 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 <type>boolean</type> 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 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 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 box (data type) 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 path (data type) 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 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 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 network addresses PostgreSQL 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. <type>inet</type> inet (data type) 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. <type>cidr</> 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: <type>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
<type>inet</type> vs <type>cidr</type> 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. <type>macaddr</></> <indexterm> <primary>macaddr (data type)</primary> </indexterm> <indexterm> <primary>MAC address</primary> <see>macaddr</see> </indexterm> <para> The <type>macaddr</> type stores MAC addresses, i.e., Ethernet card hardware addresses (although MAC addresses are used for other purposes as well). Input is accepted in various customary formats, including <simplelist> <member><literal>'08002b:010203'</></member> <member><literal>'08002b-010203'</></member> <member><literal>'0800.2b01.0203'</></member> <member><literal>'08-00-2b-01-02-03'</></member> <member><literal>'08:00:2b:01:02:03'</></member> </simplelist> which would all specify the same address. Upper and lower case is accepted for the digits <literal>a</> through <literal>f</>. Output is always in the last of the shown forms. </para> <para> The directory <filename class="directory">contrib/mac</filename> in the <productname>PostgreSQL</productname> source distribution contains tools that can be used to map MAC addresses to hardware manufacturer names. </para> </sect2> </sect1> <sect1 id="datatype-bit"> <title>Bit String Types bit strings data type 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); where x is a positive integer. BIT type data must match the length x exactly; it is an error to attempt to store shorter or longer bit strings. BIT VARYING is of variable length up to the maximum length x; longer strings will be rejected. BIT without length is equivalent to BIT(1), BIT VARYING without length specification means unlimited length. Prior to PostgreSQL 7.2, BIT type data was zero-padded on the right. This was changed to comply with the SQL standard. To implement zero-padded bit strings, a combination of the concatenation operator and the substring function can be used. Refer to for information about the syntax of bit string constants. Bit-logical operators and string manipulation functions are available; see . Using the bit string types CREATE TABLE test (a BIT(3), b BIT VARYING(5)); INSERT INTO test VALUES (B'101', B'00'); INSERT INTO test VALUES (B'10', B'101'); ERROR: bit string length does not match type bit(3) SELECT SUBSTRING(b FROM 1 FOR 2) FROM test;