Functions and Operators functions operators PostgreSQL provides a large number of functions and operators for the built-in data types. Users can also define their own functions and operators, as described in the Programmer's Guide. The psql commands \df and \do can be used to show the list of all actually available functions and operators, respectively. If you are concerned about portability then take note that most of the functions and operators described in this chapter, with the exception of the most trivial arithmetic and comparison operators and some explicitly marked functions, are not specified by the SQL standard. Some of this extended functionality is present in other RDBMS products, and in many cases this functionality is compatible and consistent between various products. Logical Operators operators logical Boolean operators operators, logical The usual logical operators are available: and operator or operator not operator AND OR NOT SQL uses a three-valued Boolean logic where the null value represents unknown. Observe the following truth tables: a b a AND b a OR b TRUE TRUE TRUE TRUE TRUE FALSE FALSE TRUE TRUE NULL NULL TRUE FALSE FALSE FALSE FALSE FALSE NULL FALSE NULL NULL NULL NULL NULL a NOT a TRUE FALSE FALSE TRUE NULL NULL Comparison Operators comparison operators Comparison Operators Operator Description < less than > greater than <= less than or equal to >= greater than or equal to = equal <> or != not equal
The != operator is converted to <> in the parser stage. It is not possible to implement != and <> operators that do different things. Comparison operators are available for all data types where this makes sense. All comparison operators are binary operators that return values of type boolean; expressions like 1 < 2 < 3 are not valid (because there is no < operator to compare a Boolean value with 3). between In addition to the comparison operators, the special BETWEEN construct is available. a BETWEEN x AND y is equivalent to a >= x AND a <= y Similarly, a NOT BETWEEN x AND y is equivalent to a < x OR a > y There is no difference between the two respective forms apart from the CPU cycles required to rewrite the first one into the second one internally. To check whether a value is or is not null, use the constructs expression IS NULL expression IS NOT NULL or the equivalent, but less standard, constructs expression ISNULL expression NOTNULL Do not write expression = NULL because NULL is not equal to NULL. (The null value represents an unknown value, and it is not known whether two unknown values are equal.) Some applications may (incorrectly) require that expression = NULL returns true if expression evaluates to the null value. To support these applications, the run-time option transform_null_equals can be turned on (e.g., SET transform_null_equals TO ON;). PostgreSQL will then convert x = NULL clauses to x IS NULL. This was the default behavior in releases 6.5 through 7.1. Boolean values can also be tested using the constructs expression IS TRUE expression IS NOT TRUE expression IS FALSE expression IS NOT FALSE expression IS UNKNOWN expression IS NOT UNKNOWN These are similar to IS NULL in that they will always return true or false, never a null value, even when the operand is null. A null input is treated as the logical value unknown.
Mathematical Functions and Operators Mathematical operators are provided for many PostgreSQL types. For types without common mathematical conventions for all possible permutations (e.g. date/time types) we describe the actual behavior in subsequent sections. Mathematical Operators Name Description Example Result + Addition 2 + 3 5 - Subtraction 2 - 3 -1 * Multiplication 2 * 3 6 / Division (integer division truncates results) 4 / 2 2 % Modulo (remainder) 5 % 4 1 ^ Exponentiation 2.0 ^ 3.0 8 |/ Square root |/ 25.0 5 ||/ Cube root ||/ 27.0 3 ! Factorial 5 ! 120 !! Factorial (prefix operator) !! 5 120 @ Absolute value @ -5.0 5 & Binary AND 91 & 15 11 | Binary OR 32 | 3 35 # Binary XOR 17 # 5 20 ~ Binary NOT ~1 -2 << Binary shift left 1 << 4 16 >> Binary shift right 8 >> 2 2
The binary operators are also available for the bit string types BIT and BIT VARYING. Bit String Binary Operators Example Result B'10001' & B'01101' 00001 B'10001' | B'01101' 11101 B'10001' # B'01101' 11110 ~ B'10001' 01110 B'10001' << 3 01000 B'10001' >> 2 00100
Bit string arguments to &, |, and # must be of equal length. When bit shifting, the original length of the string is preserved, as shown here.
Mathematical Functions Function Return Type Description Example Result abs(x) (same as x) absolute value abs(-17.4) 17.4 cbrt(dp) dp cube root cbrt(27.0) 3 ceil(numeric) numeric smallest integer not less than argument ceil(-42.8) -42 degrees(dp) dp radians to degrees degrees(0.5) 28.6478897565412 exp(dp) dp exponential exp(1.0) 2.71828182845905 floor(numeric) numeric largest integer not greater than argument floor(-42.8) -43 ln(dp) dp natural logarithm ln(2.0) 0.693147180559945 log(dp) dp base 10 logarithm log(100.0) 2 log(b numeric, x numeric) numeric logarithm to base b log(2.0, 64.0) 6.0000000000 mod(y, x) (same as argument types) remainder of y/x mod(9,4) 1 pi() dp Pi constant pi() 3.14159265358979 pow(e dp, n dp) dp raise a number to exponent e pow(9.0, 3.0) 729 radians(dp) dp degrees to radians radians(45.0) 0.785398163397448 random() dp value between 0.0 to 1.0 random() round(dp) dp round to nearest integer round(42.4) 42 round(v numeric, s integer) numeric round to s decimal places round(42.4382, 2) 42.44 sign(numeric) numeric sign of the argument (-1, 0, +1) sign(-8.4) -1 sqrt(dp) dp square root sqrt(2.0) 1.4142135623731 trunc(dp) dp truncate toward zero trunc(42.8) 42 trunc(numeric, r integer) numeric truncate to s decimal places trunc(42.4382, 2) 42.43
In the table above, dp indicates double precision. The functions exp, ln, log, pow, round (1 argument), sqrt, and trunc (1 argument) are also available for the type numeric in place of double precision. Functions returning a numeric result take numeric input arguments, unless otherwise specified. Many of these functions are implemented on top of the host system's C library; accuracy and behavior in boundary cases could therefore vary depending on the host system. Trigonometric Functions Function Description acos(x) inverse cosine asin(x) inverse sine atan(x) inverse tangent atan2(x, y) inverse tangent of x/y cos(x) cosine cot(x) cotangent sin(x) sine tan(x) tangent
All trigonometric functions have arguments and return values of type double precision.
String Functions and Operators This section describes functions and operators for examining and manipulating string values. Strings in this context include values of all the types CHARACTER, CHARACTER VARYING, and TEXT. Unless otherwise noted, all of the functions listed below work on all of these types, but be wary of potential effects of the automatic padding when using the CHARACTER type. Generally, the functions described here also work on data of non-string types by converting that data to a string representation first. Some functions also exist natively for bit-string types. SQL defines some string functions with a special syntax where certain keywords rather than commas are used to separate the arguments. Details are in . These functions are also implemented using the regular syntax for function invocation. (See .) <acronym>SQL</acronym> String Functions and Operators Function Return Type Description Example Result string || string text string concatenation character strings concatenation 'Postgre' || 'SQL' PostgreSQL bit_length(string) integer number of bits in string bit_length('jose') 32 char_length(string) or character_length(string) integer number of characters in string character strings length length character strings character strings, length char_length('jose') 4 convert(string using conversion_name) text Change encoding using specified conversion name. Conversions can be defined by CREATE CONVERSION. Also there are some pre-defined conversion names. See for available conversion names. convert('PostgreSQL' using iso_8859_1_to_utf_8) 'PostgreSQL' in UNICODE (UTF-8) encoding lower(string) text Convert string to lower case. lower('TOM') tom octet_length(string) integer number of bytes in string octet_length('jose') 4 overlay(string placing string from integer for integer) text insert substring overlay overlay('Txxxxas' placing 'hom' from 2 for 4) Thomas position(substring in string) integer location of specified substring position('om' in 'Thomas') 3 substring(string from integer for integer) text extract substring substring substring('Thomas' from 2 for 3) hom substring(string from pattern) text extract substring matching POSIX regular expression substring substring('Thomas' from '...$') mas substring(string from pattern for escape) text extract substring matching SQL99 regular expression substring substring('Thomas' from '%#"o_a#"_' for '#') oma trim(leading | trailing | both characters from string) text Removes the longest string containing only the characters (a space by default) from the beginning/end/both ends of the string. trim(both 'x' from 'xTomxx') Tom upper(string) text Convert string to upper case. upper('tom') TOM
Additional string manipulation functions are available and are listed below. Some of them are used internally to implement the SQL-standard string functions listed above. Other String Functions Function Return Type Description Example Result ascii(text) integer Returns the ASCII code of the first character of the argument. ascii('x') 120 btrim(string text, trim text) text Remove (trim) the longest string consisting only of characters in trim from the start and end of string. btrim('xyxtrimyyx','xy') trim chr(integer) text Returns the character with the given ASCII code. chr(65) A convert(string text, src_encoding name, dest_encoding name) text Converts string using dest_encoding. The original encoding is specified by src_encoding. If src_encoding is omitted, database encoding is assumed. convert('text_in_unicode', 'UNICODE', 'LATIN1') text_in_unicode represented in ISO 8859-1 decode(string text, type text) bytea Decodes binary data from string previously encoded with encode(). Parameter type is same as in encode(). decode('MTIzAAE=', 'base64') 123\000\001 encode(data bytea, type text) text Encodes binary data to ASCII-only representation. Supported types are: 'base64', 'hex', 'escape'. encode('123\\000\\001', 'base64') MTIzAAE= initcap(text) text Converts first letter of each word (whitespace separated) to upper case. initcap('hi thomas') Hi Thomas length(string) integer length of string character strings length length character strings character strings, length length('jose') 4 lpad(string text, length integer , fill text) text Fills up the string to length length by prepending the characters fill (a space by default). If the string is already longer than length then it is truncated (on the right). lpad('hi', 5, 'xy') xyxhi ltrim(string text, text text) text Removes the longest string containing only characters from trim from the start of the string. ltrim('zzzytrim','xyz') trim pg_client_encoding() name Returns current client encoding name. pg_client_encoding() SQL_ASCII quote_ident(string text) text Returns the given string suitably quoted to be used as an identifier in an SQL query string. Quotes are added only if necessary (i.e., if the string contains non-identifier characters or would be case-folded). Embedded quotes are properly doubled. quote_ident('Foo') "Foo" quote_literal(string text) text Returns the given string suitably quoted to be used as a literal in an SQL query string. Embedded quotes and backslashes are properly doubled. quote_literal('O\'Reilly') 'O''Reilly' repeat(text, integer) text Repeat text a number of times. repeat('Pg', 4) PgPgPgPg replace(string text, from text, to text) text Replace all occurrences in string of substring from with substring to replace('abcdefabcdef', 'cd', 'XX') abXXefabXXef rpad(string text, length integer , fill text) text Fills up the string to length length by appending the characters fill (a space by default). If the string is already longer than length then it is truncated. rpad('hi', 5, 'xy') hixyx rtrim(string text, trim text) text Removes the longest string containing only characters from trim from the end of the string. rtrim('trimxxxx','x') trim split_part(string text, delimiter text, column integer) text Split string on delimiter returning the resulting (one based) column number. split_part('abc~@~def~@~ghi','~@~',2) def strpos(string, substring) text Locates specified substring. (same as position(substring in string), but note the reversed argument order) strpos('high','ig') 2 substr(string, from , count) text Extracts specified substring. (same as substring(string from from for count)) substr('alphabet', 3, 2) ph to_ascii(text , encoding) text Converts text from multibyte encoding to ASCII. to_ascii('Karel') Karel to_hex(number integer or bigint) text Convert number to its equivalent hexadecimal representation. to_hex(9223372036854775807::bigint) 7fffffffffffffff translate(string text, from text, to text) text Any character in string that matches a character in the from set is replaced by the corresponding character in the to set. translate('12345', '14', 'ax') a23x5
The to_ascii function supports conversion from LATIN1, LATIN2, and WIN1250 only. Built-in Conversions Conversion Name The conversion names follow a standard naming scheme: The official name of the source encoding with all non-alphanumeric characters replaced by underscores followed by _to_ followed by the equally processed destination encoding name. Therefore the names might deviate from the customary encoding names. Source Encoding Destination Encoding ascii_to_mic SQL_ASCII MULE_INTERNAL ascii_to_utf_8 SQL_ASCII UNICODE big5_to_euc_tw BIG5 EUC_TW big5_to_mic BIG5 MULE_INTERNAL big5_to_utf_8 BIG5 UNICODE euc_cn_to_mic EUC_CN MULE_INTERNAL euc_cn_to_utf_8 EUC_CN UNICODE euc_jp_to_mic EUC_JP MULE_INTERNAL euc_jp_to_sjis EUC_JP SJIS euc_jp_to_utf_8 EUC_JP UNICODE euc_kr_to_mic EUC_KR MULE_INTERNAL euc_kr_to_utf_8 EUC_KR UNICODE euc_tw_to_big5 EUC_TW BIG5 euc_tw_to_mic EUC_TW MULE_INTERNAL euc_tw_to_utf_8 EUC_TW UNICODE gb18030_to_utf_8 GB18030 UNICODE gbk_to_utf_8 GBK UNICODE iso_8859_10_to_utf_8 LATIN6 UNICODE iso_8859_13_to_utf_8 LATIN7 UNICODE iso_8859_14_to_utf_8 LATIN8 UNICODE iso_8859_15_to_utf_8 LATIN9 UNICODE iso_8859_16_to_utf_8 LATIN10 UNICODE iso_8859_1_to_mic LATIN1 MULE_INTERNAL iso_8859_1_to_utf_8 LATIN1 UNICODE iso_8859_2_to_mic LATIN2 MULE_INTERNAL iso_8859_2_to_utf_8 LATIN2 UNICODE iso_8859_2_to_windows_1250 LATIN2 WIN1250 iso_8859_3_to_mic LATIN3 MULE_INTERNAL iso_8859_3_to_utf_8 LATIN3 UNICODE iso_8859_4_to_mic LATIN4 MULE_INTERNAL iso_8859_4_to_utf_8 LATIN4 UNICODE iso_8859_5_to_koi8_r ISO_8859_5 KOI8 iso_8859_5_to_mic ISO_8859_5 MULE_INTERNAL iso_8859_5_to_utf_8 ISO_8859_5 UNICODE iso_8859_5_to_windows_1251 ISO_8859_5 WIN iso_8859_5_to_windows_866 ISO_8859_5 ALT iso_8859_6_to_utf_8 ISO_8859_6 UNICODE iso_8859_7_to_utf_8 ISO_8859_7 UNICODE iso_8859_8_to_utf_8 ISO_8859_8 UNICODE iso_8859_9_to_utf_8 LATIN5 UNICODE johab_to_utf_8 JOHAB UNICODE koi8_r_to_iso_8859_5 KOI8 ISO_8859_5 koi8_r_to_mic KOI8 MULE_INTERNAL koi8_r_to_utf_8 KOI8 UNICODE koi8_r_to_windows_1251 KOI8 WIN koi8_r_to_windows_866 KOI8 ALT mic_to_ascii MULE_INTERNAL SQL_ASCII mic_to_big5 MULE_INTERNAL BIG5 mic_to_euc_cn MULE_INTERNAL EUC_CN mic_to_euc_jp MULE_INTERNAL EUC_JP mic_to_euc_kr MULE_INTERNAL EUC_KR mic_to_euc_tw MULE_INTERNAL EUC_TW mic_to_iso_8859_1 MULE_INTERNAL LATIN1 mic_to_iso_8859_2 MULE_INTERNAL LATIN2 mic_to_iso_8859_3 MULE_INTERNAL LATIN3 mic_to_iso_8859_4 MULE_INTERNAL LATIN4 mic_to_iso_8859_5 MULE_INTERNAL ISO_8859_5 mic_to_koi8_r MULE_INTERNAL KOI8 mic_to_sjis MULE_INTERNAL SJIS mic_to_windows_1250 MULE_INTERNAL WIN1250 mic_to_windows_1251 MULE_INTERNAL WIN mic_to_windows_866 MULE_INTERNAL ALT sjis_to_euc_jp SJIS EUC_JP sjis_to_mic SJIS MULE_INTERNAL sjis_to_utf_8 SJIS UNICODE tcvn_to_utf_8 TCVN UNICODE uhc_to_utf_8 UHC UNICODE utf_8_to_ascii UNICODE SQL_ASCII utf_8_to_big5 UNICODE BIG5 utf_8_to_euc_cn UNICODE EUC_CN utf_8_to_euc_jp UNICODE EUC_JP utf_8_to_euc_kr UNICODE EUC_KR utf_8_to_euc_tw UNICODE EUC_TW utf_8_to_gb18030 UNICODE GB18030 utf_8_to_gbk UNICODE GBK utf_8_to_iso_8859_1 UNICODE LATIN1 utf_8_to_iso_8859_10 UNICODE LATIN6 utf_8_to_iso_8859_13 UNICODE LATIN7 utf_8_to_iso_8859_14 UNICODE LATIN8 utf_8_to_iso_8859_15 UNICODE LATIN9 utf_8_to_iso_8859_16 UNICODE LATIN10 utf_8_to_iso_8859_2 UNICODE LATIN2 utf_8_to_iso_8859_3 UNICODE LATIN3 utf_8_to_iso_8859_4 UNICODE LATIN4 utf_8_to_iso_8859_5 UNICODE ISO_8859_5 utf_8_to_iso_8859_6 UNICODE ISO_8859_6 utf_8_to_iso_8859_7 UNICODE ISO_8859_7 utf_8_to_iso_8859_8 UNICODE ISO_8859_8 utf_8_to_iso_8859_9 UNICODE LATIN5 utf_8_to_johab UNICODE JOHAB utf_8_to_koi8_r UNICODE KOI8 utf_8_to_sjis UNICODE SJIS utf_8_to_tcvn UNICODE TCVN utf_8_to_uhc UNICODE UHC utf_8_to_windows_1250 UNICODE WIN1250 utf_8_to_windows_1251 UNICODE WIN utf_8_to_windows_1256 UNICODE WIN1256 utf_8_to_windows_866 UNICODE ALT utf_8_to_windows_874 UNICODE WIN874 windows_1250_to_iso_8859_2 WIN1250 LATIN2 windows_1250_to_mic WIN1250 MULE_INTERNAL windows_1250_to_utf_8 WIN1250 UNICODE windows_1251_to_iso_8859_5 WIN ISO_8859_5 windows_1251_to_koi8_r WIN KOI8 windows_1251_to_mic WIN MULE_INTERNAL windows_1251_to_utf_8 WIN UNICODE windows_1251_to_windows_866 WIN ALT windows_1256_to_utf_8 WIN1256 UNICODE windows_866_to_iso_8859_5 ALT ISO_8859_5 windows_866_to_koi8_r ALT KOI8 windows_866_to_mic ALT MULE_INTERNAL windows_866_to_utf_8 ALT UNICODE windows_866_to_windows_1251 ALT WIN windows_874_to_utf_8 WIN874 UNICODE
Binary String Functions and Operators This section describes functions and operators for examining and manipulating binary string values. Strings in this context include values of the type BYTEA. SQL defines some string functions with a special syntax where certain keywords rather than commas are used to separate the arguments. Details are in . Some functions are also implemented using the regular syntax for function invocation. (See .) <acronym>SQL</acronym> Binary String Functions and Operators Function Return Type Description Example Result string || string bytea string concatenation binary strings concatenation '\\\\Postgre'::bytea || '\\047SQL\\000'::bytea \\Postgre'SQL\000 octet_length(string) integer number of bytes in binary string octet_length('jo\\000se'::bytea) 5 position(substring in string) integer location of specified substring position('\\000om'::bytea in 'Th\\000omas'::bytea) 3 substring(string from integer for integer) bytea extract substring substring substring('Th\\000omas'::bytea from 2 for 3) h\000o trim(both characters from string) bytea Removes the longest string containing only the characters from the beginning/end/both ends of the string. trim('\\000'::bytea from '\\000Tom\\000'::bytea) Tom
Additional binary string manipulation functions are available and are listed below. Some of them are used internally to implement the SQL-standard string functions listed above. Other Binary String Functions Function Return Type Description Example Result btrim(string bytea trim bytea) bytea Remove (trim) the longest string consisting only of characters in trim from the start and end of string. btrim('\\000trim\\000'::bytea,'\\000'::bytea) trim length(string) integer length of binary string binary strings length length binary strings binary strings, length length('jo\\000se'::bytea) 5 encode(string bytea, type text) text Encodes binary string to ASCII-only representation. Supported types are: 'base64', 'hex', 'escape'. encode('123\\000456'::bytea, 'escape') 123\000456 decode(string text, type text) bytea Decodes binary string from string previously encoded with encode(). Parameter type is same as in encode(). decode('123\\000456', 'escape') 123\000456
Pattern Matching There are three separate approaches to pattern matching provided by PostgreSQL: the traditional SQL LIKE operator, the more recent SQL99 SIMILAR TO operator, and POSIX-style regular expressions. Additionally, a pattern matching function, SUBSTRING, is available, using either SQL99-style or POSIX-style regular expressions. If you have pattern matching needs that go beyond this, consider writing a user-defined function in Perl or Tcl. <function>LIKE</function> like string LIKE pattern ESCAPE escape-character string NOT LIKE pattern ESCAPE escape-character Every pattern defines a set of strings. The LIKE expression returns true if the string is contained in the set of strings represented by pattern. (As expected, the NOT LIKE expression returns false if LIKE returns true, and vice versa. An equivalent expression is NOT (string LIKE pattern).) If pattern does not contain percent signs or underscore, then the pattern only represents the string itself; in that case LIKE acts like the equals operator. An underscore (_) in pattern stands for (matches) any single character; a percent sign (%) matches any string of zero or more characters. Some examples: 'abc' LIKE 'abc' true 'abc' LIKE 'a%' true 'abc' LIKE '_b_' true 'abc' LIKE 'c' false LIKE pattern matches always cover the entire string. To match a pattern anywhere within a string, the pattern must therefore start and end with a percent sign. To match a literal underscore or percent sign without matching other characters, the respective character in pattern must be preceded by the escape character. The default escape character is the backslash but a different one may be selected by using the ESCAPE clause. To match the escape character itself, write two escape characters. Note that the backslash already has a special meaning in string literals, so to write a pattern constant that contains a backslash you must write two backslashes in the query. Thus, writing a pattern that actually matches a literal backslash means writing four backslashes in the query. You can avoid this by selecting a different escape character with ESCAPE; then backslash is not special to LIKE anymore. (But it is still special to the string literal parser, so you still need two of them.) It's also possible to select no escape character by writing ESCAPE ''. This effectively disables the escape mechanism, which makes it impossible to turn off the special meaning of underscore and percent signs in the pattern. The keyword ILIKE can be used instead of LIKE to make the match case insensitive according to the active locale. This is not in the SQL standard but is a PostgreSQL extension. The operator ~~ is equivalent to LIKE, and ~~* corresponds to ILIKE. There are also !~~ and !~~* operators that represent NOT LIKE and NOT ILIKE. All of these operators are PostgreSQL-specific. <function>SIMILAR TO</function> and <acronym>SQL99</acronym> Regular Expressions regular expressions similar to substring string SIMILAR TO pattern ESCAPE escape-character string NOT SIMILAR TO pattern ESCAPE escape-character The SIMILAR TO operator returns true or false depending on whether its pattern matches the given string. It is much like LIKE, except that it interprets the pattern using SQL99's definition of a regular expression. SQL99's regular expressions are a curious cross between LIKE notation and common regular expression notation. Like LIKE, the SIMILAR TO operator succeeds only if its pattern matches the entire string; this is unlike common regular expression practice, wherein the pattern may match any part of the string. Also like LIKE, SIMILAR TO uses % and _ as wildcard characters denoting any string and any single character, respectively (these are comparable to .* and . in POSIX regular expressions). In addition to these facilities borrowed from LIKE, SIMILAR TO supports these pattern-matching metacharacters borrowed from POSIX regular expressions: | denotes alternation (either of two alternatives). * denotes repetition of the previous item zero or more times. + denotes repetition of the previous item one or more times. Parentheses () may be used to group items into a single logical item. A bracket expression [...] specifies a character class, just as in POSIX regular expressions. Notice that bounded repetition (? and {...}) are not provided, though they exist in POSIX. Also, dot (.) is not a metacharacter. As with LIKE, a backslash disables the special meaning of any of these metacharacters; or a different escape character can be specified with ESCAPE. Some examples: 'abc' SIMILAR TO 'abc' true 'abc' SIMILAR TO 'a' false 'abc' SIMILAR TO '%(b|d)%' true 'abc' SIMILAR TO '(b|c)%' false The SUBSTRING function with three parameters, SUBSTRING(string FROM pattern FOR escape), provides extraction of a substring that matches a SQL99 regular expression pattern. As with SIMILAR TO, the specified pattern must match to the entire data string, else the function fails and returns NULL. To indicate the part of the pattern that should be returned on success, SQL99 specifies that the pattern must contain two occurrences of the escape character followed by double quote ("). The text matching the portion of the pattern between these markers is returned. Some examples: SUBSTRING('foobar' FROM '%#"o_b#"%' FOR '#') oob SUBSTRING('foobar' FROM '#"o_b#"%' FOR '#') NULL <acronym>POSIX</acronym> Regular Expressions regular expressions pattern matching Regular Expression Match Operators Operator Description Example ~ Matches regular expression, case sensitive 'thomas' ~ '.*thomas.*' ~* Matches regular expression, case insensitive 'thomas' ~* '.*Thomas.*' !~ Does not match regular expression, case sensitive 'thomas' !~ '.*Thomas.*' !~* Does not match regular expression, case insensitive 'thomas' !~* '.*vadim.*'
POSIX regular expressions provide a more powerful means for pattern matching than the LIKE and SIMILAR TO operators. Many Unix tools such as egrep, sed, or awk use a pattern matching language that is similar to the one described here. A regular expression is a character sequence that is an abbreviated definition of a set of strings (a regular set). A string is said to match a regular expression if it is a member of the regular set described by the regular expression. As with LIKE, pattern characters match string characters exactly unless they are special characters in the regular expression language --- but regular expressions use different special characters than LIKE does. Unlike LIKE patterns, a regular expression is allowed to match anywhere within a string, unless the regular expression is explicitly anchored to the beginning or end of the string. Some examples: 'abc' ~ 'abc' true 'abc' ~ '^a' true 'abc' ~ '(b|d)' true 'abc' ~ '^(b|c)' false The SUBSTRING function with two parameters, SUBSTRING(string FROM pattern), provides extraction of a substring that matches a POSIX regular expression pattern. It returns NULL if there is no match, otherwise the portion of the text that matched the pattern. But if the pattern contains any parentheses, the portion of the text that matched the first parenthesized subexpression (the one whose left parenthesis comes first) is returned. You can always put parentheses around the whole expression if you want to use parentheses within it without triggering this exception. Some examples: SUBSTRING('foobar' FROM 'o.b') oob SUBSTRING('foobar' FROM 'o(.)b') o Regular expressions (REs), as defined in POSIX 1003.2, come in two forms: modern REs (roughly those of egrep; 1003.2 calls these extended REs) and obsolete REs (roughly those of ed; 1003.2 basic REs). PostgreSQL implements the modern form. A (modern) RE is one or more non-empty branches, separated by |. It matches anything that matches one of the branches. A branch is one or more pieces, concatenated. It matches a match for the first, followed by a match for the second, etc. A piece is an atom possibly followed by a single *, +, ?, or bound. An atom followed by * matches a sequence of 0 or more matches of the atom. An atom followed by + matches a sequence of 1 or more matches of the atom. An atom followed by ? matches a sequence of 0 or 1 matches of the atom. A bound is { followed by an unsigned decimal integer, possibly followed by , possibly followed by another unsigned decimal integer, always followed by }. The integers must lie between 0 and RE_DUP_MAX (255) inclusive, and if there are two of them, the first may not exceed the second. An atom followed by a bound containing one integer i and no comma matches a sequence of exactly i matches of the atom. An atom followed by a bound containing one integer i and a comma matches a sequence of i or more matches of the atom. An atom followed by a bound containing two integers i and j matches a sequence of i through j (inclusive) matches of the atom. A repetition operator (?, *, +, or bounds) cannot follow another repetition operator. A repetition operator cannot begin an expression or subexpression or follow ^ or |. An atom is a regular expression enclosed in () (matching a match for the regular expression), an empty set of () (matching the null string), a bracket expression (see below), . (matching any single character), ^ (matching the null string at the beginning of the input string), $ (matching the null string at the end of the input string), a \ followed by one of the characters ^.[$()|*+?{\ (matching that character taken as an ordinary character), a \ followed by any other character (matching that character taken as an ordinary character, as if the \ had not been present), or a single character with no other significance (matching that character). A { followed by a character other than a digit is an ordinary character, not the beginning of a bound. It is illegal to end an RE with \. Note that the backslash (\) already has a special meaning in string literals, so to write a pattern constant that contains a backslash you must write two backslashes in the query. A bracket expression is a list of characters enclosed in []. It normally matches any single character from the list (but see below). If the list begins with ^, it matches any single character (but see below) not from the rest of the list. If two characters in the list are separated by -, this is shorthand for the full range of characters between those two (inclusive) in the collating sequence, e.g. [0-9] in ASCII matches any decimal digit. It is illegal for two ranges to share an endpoint, e.g. a-c-e. Ranges are very collating-sequence-dependent, and portable programs should avoid relying on them. To include a literal ] in the list, make it the first character (following a possible ^). To include a literal -, make it the first or last character, or the second endpoint of a range. To use a literal - as the first endpoint of a range, enclose it in [. and .] to make it a collating element (see below). With the exception of these and some combinations using [ (see next paragraphs), all other special characters, including \, lose their special significance within a bracket expression. Within a bracket expression, a collating element (a character, a multiple-character sequence that collates as if it were a single character, or a collating-sequence name for either) enclosed in [. and .] stands for the sequence of characters of that collating element. The sequence is a single element of the bracket expression's list. A bracket expression containing a multiple-character collating element can thus match more than one character, e.g. if the collating sequence includes a ch collating element, then the RE [[.ch.]]*c matches the first five characters of chchcc. Within a bracket expression, a collating element enclosed in [= and =] is an equivalence class, standing for the sequences of characters of all collating elements equivalent to that one, including itself. (If there are no other equivalent collating elements, the treatment is as if the enclosing delimiters were [. and .].) For example, if o and ^ are the members of an equivalence class, then [[=o=]], [[=^=]], and [o^] are all synonymous. An equivalence class may not be an endpoint of a range. Within a bracket expression, the name of a character class enclosed in [: and :] stands for the list of all characters belonging to that class. Standard character class names are: alnum, alpha, blank, cntrl, digit, graph, lower, print, punct, space, upper, xdigit. These stand for the character classes defined in ctype3. A locale may provide others. A character class may not be used as an endpoint of a range. There are two special cases of bracket expressions: the bracket expressions [[:<:]] and [[:>:]] match the null string at the beginning and end of a word respectively. A word is defined as a sequence of word characters which is neither preceded nor followed by word characters. A word character is an alnum character (as defined by ctype3) or an underscore. This is an extension, compatible with but not specified by POSIX 1003.2, and should be used with caution in software intended to be portable to other systems. In the event that an RE could match more than one substring of a given string, the RE matches the one starting earliest in the string. If the RE could match more than one substring starting at that point, it matches the longest. Subexpressions also match the longest possible substrings, subject to the constraint that the whole match be as long as possible, with subexpressions starting earlier in the RE taking priority over ones starting later. Note that higher-level subexpressions thus take priority over their lower-level component subexpressions. Match lengths are measured in characters, not collating elements. A null string is considered longer than no match at all. For example, bb* matches the three middle characters of abbbc, (wee|week)(knights|nights) matches all ten characters of weeknights, when (.*).* is matched against abc the parenthesized subexpression matches all three characters, and when (a*)* is matched against bc both the whole RE and the parenthesized subexpression match the null string. If case-independent matching is specified, the effect is much as if all case distinctions had vanished from the alphabet. When an alphabetic that exists in multiple cases appears as an ordinary character outside a bracket expression, it is effectively transformed into a bracket expression containing both cases, e.g. x becomes [xX]. When it appears inside a bracket expression, all case counterparts of it are added to the bracket expression, so that (e.g.) [x] becomes [xX] and [^x] becomes [^xX]. There is no particular limit on the length of REs, except insofar as memory is limited. Memory usage is approximately linear in RE size, and largely insensitive to RE complexity, except for bounded repetitions. Bounded repetitions are implemented by macro expansion, which is costly in time and space if counts are large or bounded repetitions are nested. An RE like, say, ((((a{1,100}){1,100}){1,100}){1,100}){1,100} will (eventually) run almost any existing machine out of swap space. This was written in 1994, mind you. The numbers have probably changed, but the problem persists.
Data Type Formatting Functions formatting Author Written by Karel Zak (zakkr@zf.jcu.cz) on 2000-01-24 The PostgreSQL formatting functions provide a powerful set of tools for converting various data types (date/time, integer, floating point, numeric) to formatted strings and for converting from formatted strings to specific data types. These functions all follow a common calling convention: the first argument is the value to be formatted and the second argument is a template that defines the output or input format. Formatting Functions Function Returns Description Example to_char(timestamp, text) text convert time stamp to string to_char(timestamp 'now','HH12:MI:SS') to_char(interval, text) text convert interval to string to_char(interval '15h 2m 12s','HH24:MI:SS') to_char(int, text) text convert int4/int8 to string to_char(125, '999') to_char(double precision, text) text convert real/double precision to string to_char(125.8, '999D9') to_char(numeric, text) text convert numeric to string to_char(numeric '-125.8', '999D99S') to_date(text, text) date convert string to date to_date('05 Dec 2000', 'DD Mon YYYY') to_timestamp(text, text) timestamp convert string to time stamp to_timestamp('05 Dec 2000', 'DD Mon YYYY') to_number(text, text) numeric convert string to numeric to_number('12,454.8-', '99G999D9S')
In an output template string, there are certain patterns that are recognized and replaced with appropriately-formatted data from the value to be formatted. Any text that is not a template pattern is simply copied verbatim. Similarly, in an input template string, template patterns identify the parts of the input data string to be looked at and the values to be found there. Template patterns for date/time conversions Pattern Description HH hour of day (01-12) HH12 hour of day (01-12) HH24 hour of day (00-23) MI minute (00-59) SS second (00-59) MS millisecond (000-999) US microsecond (000000-999999) SSSS seconds past midnight (0-86399) AM or A.M. or PM or P.M. meridian indicator (upper case) am or a.m. or pm or p.m. meridian indicator (lower case) Y,YYY year (4 and more digits) with comma YYYY year (4 and more digits) YYY last 3 digits of year YY last 2 digits of year Y last digit of year BC or B.C. or AD or A.D. era indicator (upper case) bc or b.c. or ad or a.d. era indicator (lower case) MONTH full upper case month name (blank-padded to 9 chars) Month full mixed case month name (blank-padded to 9 chars) month full lower case month name (blank-padded to 9 chars) MON abbreviated upper case month name (3 chars) Mon abbreviated mixed case month name (3 chars) mon abbreviated lower case month name (3 chars) MM month number (01-12) DAY full upper case day name (blank-padded to 9 chars) Day full mixed case day name (blank-padded to 9 chars) day full lower case day name (blank-padded to 9 chars) DY abbreviated upper case day name (3 chars) Dy abbreviated mixed case day name (3 chars) dy abbreviated lower case day name (3 chars) DDD day of year (001-366) DD day of month (01-31) D day of week (1-7; SUN=1) W week of month (1-5) where first week start on the first day of the month WW week number of year (1-53) where first week start on the first day of the year IW ISO week number of year (The first Thursday of the new year is in week 1.) CC century (2 digits) J Julian Day (days since January 1, 4712 BC) Q quarter RM month in Roman Numerals (I-XII; I=January) - upper case rm month in Roman Numerals (I-XII; I=January) - lower case TZ timezone name - upper case tz timezone name - lower case
Certain modifiers may be applied to any template pattern to alter its behavior. For example, FMMonth is the Month pattern with the FM prefix. Template pattern modifiers for date/time conversions Modifier Description Example FM prefix fill mode (suppress padding blanks and zeroes) FMMonth TH suffix add upper-case ordinal number suffix DDTH th suffix add lower-case ordinal number suffix DDth FX prefix Fixed format global option (see below) FX Month DD Day SP suffix spell mode (not yet implemented) DDSP
Usage notes: FM suppresses leading zeroes or trailing blanks that would otherwise be added to make the output of a pattern be fixed-width. to_timestamp and to_date skip multiple blank spaces in the input string if the FX option is not used. FX must be specified as the first item in the template; for example to_timestamp('2000 JUN','YYYY MON') is right, but to_timestamp('2000 JUN','FXYYYY MON') returns an error, because to_timestamp expects one blank space only. If a backslash (\) is desired in a string constant, a double backslash (\\) must be entered; for example '\\HH\\MI\\SS'. This is true for any string constant in PostgreSQL. Ordinary text is allowed in to_char templates and will be output literally. You can put a substring in double quotes to force it to be interpreted as literal text even if it contains pattern keywords. For example, in '"Hello Year: "YYYY', the YYYY will be replaced by year data, but the single Y will not be. If you want to have a double quote in the output you must precede it with a backslash, for example '\\"YYYY Month\\"'. YYYY conversion from string to timestamp or date is restricted if you use a year with more than 4 digits. You must use some non-digit character or template after YYYY, otherwise the year is always interpreted as 4 digits. For example (with year 20000): to_date('200001131', 'YYYYMMDD') will be interpreted as a 4-digit year; better is to use a non-digit separator after the year, like to_date('20000-1131', 'YYYY-MMDD') or to_date('20000Nov31', 'YYYYMonDD'). Millisecond MS and microsecond US values in a conversion from string to time stamp are used as part of the seconds after the decimal point. For example to_timestamp('12:3', 'SS:MS') is not 3 milliseconds, but 300, because the conversion counts it as 12 + 0.3. This means for the format SS:MS, the input values 12:3, 12:30, and 12:300 specify the same number of milliseconds. To get three milliseconds, one must use 12:003, which the conversion counts as 12 + 0.003 = 12.003 seconds. Here is a more complex example: to_timestamp('15:12:02.020.001230','HH:MI:SS.MS.US') is 15 hours, 12 minutes, and 2 seconds + 20 milliseconds + 1230 microseconds = 2.021230 seconds. Template patterns for numeric conversions Pattern Description 9 value with the specified number of digits 0 value with leading zeros . (period) decimal point , (comma) group (thousand) separator PR negative value in angle brackets S negative value with minus sign (uses locale) L currency symbol (uses locale) D decimal point (uses locale) G group separator (uses locale) MI minus sign in specified position (if number < 0) PL plus sign in specified position (if number > 0) SG plus/minus sign in specified position RN roman numeral (input between 1 and 3999) TH or th convert to ordinal number V shift n digits (see notes) EEEE scientific notation (not implemented yet)
Usage notes: A sign formatted using SG, PL, or MI is not an anchor in the number; for example, to_char(-12, 'S9999') produces ' -12', but to_char(-12, 'MI9999') produces '- 12'. The Oracle implementation does not allow the use of MI ahead of 9, but rather requires that 9 precede MI. 9 specifies a value with the same number of digits as there are 9s. If a digit is not available use blank space. TH does not convert values less than zero and does not convert decimal numbers. PL, SG, and TH are PostgreSQL extensions. V effectively multiplies the input values by 10^n, where n is the number of digits following V. to_char does not support the use of V combined with a decimal point. (E.g., 99.9V99 is not allowed.) <function>to_char</function> Examples Input Output to_char(now(),'Day, DD HH12:MI:SS') 'Tuesday , 06 05:39:18' to_char(now(),'FMDay, FMDD HH12:MI:SS') 'Tuesday, 6 05:39:18' to_char(-0.1,'99.99') ' -.10' to_char(-0.1,'FM9.99') '-.1' to_char(0.1,'0.9') ' 0.1' to_char(12,'9990999.9') ' 0012.0' to_char(12,'FM9990999.9') '0012' to_char(485,'999') ' 485' to_char(-485,'999') '-485' to_char(485,'9 9 9') ' 4 8 5' to_char(1485,'9,999') ' 1,485' to_char(1485,'9G999') ' 1 485' to_char(148.5,'999.999') ' 148.500' to_char(148.5,'999D999') ' 148,500' to_char(3148.5,'9G999D999') ' 3 148,500' to_char(-485,'999S') '485-' to_char(-485,'999MI') '485-' to_char(485,'999MI') '485' to_char(485,'PL999') '+485' to_char(485,'SG999') '+485' to_char(-485,'SG999') '-485' to_char(-485,'9SG99') '4-85' to_char(-485,'999PR') '<485>' to_char(485,'L999') 'DM 485 to_char(485,'RN') ' CDLXXXV' to_char(485,'FMRN') 'CDLXXXV' to_char(5.2,'FMRN') V to_char(482,'999th') ' 482nd' to_char(485, '"Good number:"999') 'Good number: 485' to_char(485.8,'"Pre:"999" Post:" .999') 'Pre: 485 Post: .800' to_char(12,'99V999') ' 12000' to_char(12.4,'99V999') ' 12400' to_char(12.45, '99V9') ' 125'
Date/Time Functions and Operators shows the available functions for date/time value processing. illustrates the behaviors of the basic arithmetic operators (+, *, etc.). For formatting functions, refer to . You should be familiar with the background information on date/time data types (see ). The date/time operators described below behave similarly for types involving time zones as well as those without. Date/Time Operators Name Example Result + timestamp '2001-09-28 01:00' + interval '23 hours' timestamp '2001-09-29 00:00' + date '2001-09-28' + interval '1 hour' timestamp '2001-09-28 01:00' + time '01:00' + interval '3 hours' time '04:00' - timestamp '2001-09-28 23:00' - interval '23 hours' timestamp '2001-09-28' - date '2001-09-28' - interval '1 hour' timestamp '2001-09-27 23:00' - time '05:00' - interval '2 hours' time '03:00' - interval '2 hours' - time '05:00' time '03:00:00' * interval '1 hour' * int '3' interval '03:00' / interval '1 hour' / int '3' interval '00:20'
The date/time functions are summarized below, with additional details in subsequent sections. Date/Time Functions Name Return Type Description Example Result age(timestamp) interval Subtract from today age(timestamp '1957-06-13') 43 years 8 mons 3 days age(timestamp, timestamp) interval Subtract arguments age('2001-04-10', timestamp '1957-06-13') 43 years 9 mons 27 days current_date date Today's date; see below current_time time with time zone Time of day; see below current_timestamp timestamp with time zone Date and time; see below date_part(text, timestamp) double precision Get subfield (equivalent to extract); see also below date_part('hour', timestamp '2001-02-16 20:38:40') 20 date_part(text, interval) double precision Get subfield (equivalent to extract); see also below date_part('month', interval '2 years 3 months') 3 date_trunc(text, timestamp) timestamp Truncate to specified precision; see also below date_trunc('hour', timestamp '2001-02-16 20:38:40') 2001-02-16 20:00:00+00 extract(field from timestamp) double precision Get subfield; see also below extract(hour from timestamp '2001-02-16 20:38:40') 20 extract(field from interval) double precision Get subfield; see also below extract(month from interval '2 years 3 months') 3 isfinite(timestamp) boolean Test for finite time stamp (neither invalid nor infinity) isfinite(timestamp '2001-02-16 21:28:30') true isfinite(interval) boolean Test for finite interval isfinite(interval '4 hours') true localtime time Time of day; see below localtimestamp timestamp Date and time; see below now() timestamp Current date and time (equivalent to current_timestamp); see below timeofday() text Current date and time; see below timeofday() Wed Feb 21 17:01:13.000126 2001 EST
<function>EXTRACT</function>, <function>date_part</function> EXTRACT (field FROM source) The extract function retrieves sub-fields from date/time values, such as year or hour. source is a value expression that evaluates to type timestamp or interval. (Expressions of type date or time will be cast to timestamp and can therefore be used as well.) field is an identifier or string that selects what field to extract from the source value. The extract function returns values of type double precision. The following are valid values: century The year field divided by 100 SELECT EXTRACT(CENTURY FROM TIMESTAMP '2001-02-16 20:38:40'); Result: 20 Note that the result for the century field is simply the year field divided by 100, and not the conventional definition which puts most years in the 1900's in the twentieth century. day The day (of the month) field (1 - 31) SELECT EXTRACT(DAY FROM TIMESTAMP '2001-02-16 20:38:40'); Result: 16 decade The year field divided by 10 SELECT EXTRACT(DECADE FROM TIMESTAMP '2001-02-16 20:38:40'); Result: 200 dow The day of the week (0 - 6; Sunday is 0) (for timestamp values only) SELECT EXTRACT(DOW FROM TIMESTAMP '2001-02-16 20:38:40'); Result: 5 doy The day of the year (1 - 365/366) (for timestamp values only) SELECT EXTRACT(DOY FROM TIMESTAMP '2001-02-16 20:38:40'); Result: 47 epoch For date and timestamp values, the number of seconds since 1970-01-01 00:00:00-00 (Result may be negative.); for interval values, the total number of seconds in the interval SELECT EXTRACT(EPOCH FROM TIMESTAMP '2001-02-16 20:38:40'); Result: 982352320 SELECT EXTRACT(EPOCH FROM INTERVAL '5 days 3 hours'); Result: 442800 hour The hour field (0 - 23) SELECT EXTRACT(HOUR FROM TIMESTAMP '2001-02-16 20:38:40'); Result: 20 microseconds The seconds field, including fractional parts, multiplied by 1 000 000. Note that this includes full seconds. SELECT EXTRACT(MICROSECONDS FROM TIME '17:12:28.5'); Result: 28500000 millennium The year field divided by 1000 SELECT EXTRACT(MILLENNIUM FROM TIMESTAMP '2001-02-16 20:38:40'); Result: 2 Note that the result for the millennium field is simply the year field divided by 1000, and not the conventional definition which puts years in the 1900's in the second millennium. milliseconds The seconds field, including fractional parts, multiplied by 1000. Note that this includes full seconds. SELECT EXTRACT(MILLISECONDS FROM TIME '17:12:28.5'); Result: 28500 minute The minutes field (0 - 59) SELECT EXTRACT(MINUTE FROM TIMESTAMP '2001-02-16 20:38:40'); Result: 38 month For timestamp values, the number of the month within the year (1 - 12) ; for interval values the number of months, modulo 12 (0 - 11) SELECT EXTRACT(MONTH FROM TIMESTAMP '2001-02-16 20:38:40'); Result: 2 SELECT EXTRACT(MONTH FROM INTERVAL '2 years 3 months'); Result: 3 SELECT EXTRACT(MONTH FROM INTERVAL '2 years 13 months'); Result: 1 quarter The quarter of the year (1 - 4) that the day is in (for timestamp values only) SELECT EXTRACT(QUARTER FROM TIMESTAMP '2001-02-16 20:38:40'); Result: 1 second The seconds field, including fractional parts (0 - 5960 if leap seconds are implemented by the operating system) SELECT EXTRACT(SECOND FROM TIMESTAMP '2001-02-16 20:38:40'); Result: 40 SELECT EXTRACT(SECOND FROM TIME '17:12:28.5'); Result: 28.5 timezone_hour The hour component of the time zone offset. timezone_minute The minute component of the time zone offset. week From a timestamp value, calculate the number of the week of the year that the day is in. By definition (ISO 8601), the first week of a year contains January 4 of that year. (The ISO week starts on Monday.) In other words, the first Thursday of a year is in week 1 of that year. SELECT EXTRACT(WEEK FROM TIMESTAMP '2001-02-16 20:38:40'); Result: 7 year The year field SELECT EXTRACT(YEAR FROM TIMESTAMP '2001-02-16 20:38:40'); Result: 2001 The extract function is primarily intended for computational processing. For formatting date/time values for display, see . The date_part function is modeled on the traditional Ingres equivalent to the SQL-function extract: date_part('field', source) Note that here the field value needs to be a string. The valid field values for date_part are the same as for extract. SELECT date_part('day', TIMESTAMP '2001-02-16 20:38:40'); Result: 16 SELECT date_part('hour', INTERVAL '4 hours 3 minutes'); Result: 4 <function>date_trunc</function> The function date_trunc is conceptually similar to the trunc function for numbers. date_trunc('field', source) source is a value expression of type timestamp (values of type date and time are cast automatically). field selects to which precision to truncate the time stamp value. The return value is of type timestamp with all fields that are less than the selected one set to zero (or one, for day and month). Valid values for field are: microseconds milliseconds second minute hour day month year decade century millennium SELECT date_trunc('hour', TIMESTAMP '2001-02-16 20:38:40'); Result: 2001-02-16 20:00:00+00 SELECT date_trunc('year', TIMESTAMP '2001-02-16 20:38:40'); Result: 2001-01-01 00:00:00+00 Current Date/Time date current time current The following functions are available to obtain the current date and/or time: CURRENT_DATE CURRENT_TIME CURRENT_TIMESTAMP CURRENT_TIME ( precision ) CURRENT_TIMESTAMP ( precision ) LOCALTIME LOCALTIMESTAMP LOCALTIME ( precision ) LOCALTIMESTAMP ( precision ) CURRENT_TIME, CURRENT_TIMESTAMP, LOCALTIME, and LOCALTIMESTAMP can optionally be given a precision parameter, which causes the result to be rounded to that many fractional digits. Without a precision parameter, the result is given to the full available precision. Prior to PostgreSQL 7.2, the precision parameters were unimplemented, and the result was always given in integer seconds. SELECT CURRENT_TIME; 14:39:53.662522-05 SELECT CURRENT_DATE; 2001-12-23 SELECT CURRENT_TIMESTAMP; 2001-12-23 14:39:53.662522-05 SELECT CURRENT_TIMESTAMP(2); 2001-12-23 14:39:53.66-05 SELECT LOCALTIMESTAMP; 2001-12-23 14:39:53.662522 The function now() is the traditional PostgreSQL equivalent to CURRENT_TIMESTAMP. There is also timeofday(), which for historical reasons returns a text string rather than a timestamp value: SELECT timeofday(); Sat Feb 17 19:07:32.000126 2001 EST It is important to realize that CURRENT_TIMESTAMP and related functions return the start time of the current transaction; their values do not change during the transaction. timeofday() returns the wall clock time and does advance during transactions. Many other database systems advance these values more frequently. All the date/time data types also accept the special literal value now to specify the current date and time. Thus, the following three all return the same result: SELECT CURRENT_TIMESTAMP; SELECT now(); SELECT TIMESTAMP 'now'; You do not want to use the third form when specifying a DEFAULT value while creating a table. The system will convert now to a timestamp as soon as the constant is parsed, so that when the default value is needed, the time of the table creation would be used! The first two forms will not be evaluated until the default value is used, because they are function calls. Thus they will give the desired behavior of defaulting to the time of row insertion.
Geometric Functions and Operators The geometric types point, box, lseg, line, path, polygon, and circle have a large set of native support functions and operators. Geometric Operators Operator Description Usage + Translation box '((0,0),(1,1))' + point '(2.0,0)' - Translation box '((0,0),(1,1))' - point '(2.0,0)' * Scaling/rotation box '((0,0),(1,1))' * point '(2.0,0)' / Scaling/rotation box '((0,0),(2,2))' / point '(2.0,0)' # Intersection '((1,-1),(-1,1))' # '((1,1),(-1,-1))' # Number of points in path or polygon # '((1,0),(0,1),(-1,0))' ## Point of closest proximity point '(0,0)' ## lseg '((2,0),(0,2))' && Overlaps? box '((0,0),(1,1))' && box '((0,0),(2,2))' &< Overlaps to left? box '((0,0),(1,1))' &< box '((0,0),(2,2))' &> Overlaps to right? box '((0,0),(3,3))' &> box '((0,0),(2,2))' <-> Distance between circle '((0,0),1)' <-> circle '((5,0),1)' << Left of? circle '((0,0),1)' << circle '((5,0),1)' <^ Is below? circle '((0,0),1)' <^ circle '((0,5),1)' >> Is right of? circle '((5,0),1)' >> circle '((0,0),1)' >^ Is above? circle '((0,5),1)' >^ circle '((0,0),1)' ?# Intersects or overlaps lseg '((-1,0),(1,0))' ?# box '((-2,-2),(2,2))' ?- Is horizontal? point '(1,0)' ?- point '(0,0)' ?-| Is perpendicular? lseg '((0,0),(0,1))' ?-| lseg '((0,0),(1,0))' @-@ Length or circumference @-@ path '((0,0),(1,0))' ?| Is vertical? point '(0,1)' ?| point '(0,0)' ?|| Is parallel? lseg '((-1,0),(1,0))' ?|| lseg '((-1,2),(1,2))' @ Contained or on point '(1,1)' @ circle '((0,0),2)' @@ Center of @@ circle '((0,0),10)' ~= Same as polygon '((0,0),(1,1))' ~= polygon '((1,1),(0,0))'
Geometric Functions Function Returns Description Example area(object) double precision area of item area(box '((0,0),(1,1))') box(box, box) box intersection box box(box '((0,0),(1,1))',box '((0.5,0.5),(2,2))') center(object) point center of item center(box '((0,0),(1,2))') diameter(circle) double precision diameter of circle diameter(circle '((0,0),2.0)') height(box) double precision vertical size of box height(box '((0,0),(1,1))') isclosed(path) boolean a closed path? isclosed(path '((0,0),(1,1),(2,0))') isopen(path) boolean an open path? isopen(path '[(0,0),(1,1),(2,0)]') length(object) double precision length of item length(path '((-1,0),(1,0))') npoints(path) integer number of points npoints(path '[(0,0),(1,1),(2,0)]') npoints(polygon) integer number of points npoints(polygon '((1,1),(0,0))') pclose(path) path convert path to closed popen(path '[(0,0),(1,1),(2,0)]') point(lseg,lseg) point intersection point(lseg '((-1,0),(1,0))',lseg '((-2,-2),(2,2))') ]]> popen(path) path convert path to open path popen(path '((0,0),(1,1),(2,0))') radius(circle) double precision radius of circle radius(circle '((0,0),2.0)') width(box) double precision horizontal size width(box '((0,0),(1,1))')
Geometric Type Conversion Functions Function Returns Description Example box(circle) box circle to box box(circle '((0,0),2.0)') box(point, point) box points to box box(point '(0,0)', point '(1,1)') box(polygon) box polygon to box box(polygon '((0,0),(1,1),(2,0))') circle(box) circle to circle circle(box '((0,0),(1,1))') circle(point, double precision) circle point to circle circle(point '(0,0)', 2.0) lseg(box) lseg box diagonal to lseg lseg(box '((-1,0),(1,0))') lseg(point, point) lseg points to lseg lseg(point '(-1,0)', point '(1,0)') path(polygon) point polygon to path path(polygon '((0,0),(1,1),(2,0))') point(circle) point center point(circle '((0,0),2.0)') point(lseg, lseg) point intersection point(lseg '((-1,0),(1,0))', lseg '((-2,-2),(2,2))') point(polygon) point center point(polygon '((0,0),(1,1),(2,0))') polygon(box) polygon 4-point polygon polygon(box '((0,0),(1,1))') polygon(circle) polygon 12-point polygon polygon(circle '((0,0),2.0)') polygon(npts, circle) polygon npts polygon polygon(12, circle '((0,0),2.0)') polygon(path) polygon path to polygon polygon(path '((0,0),(1,1),(2,0))')
It is possible to access the two component numbers of a point as though it were an array with subscripts 0,1. For example, if t.p is a point column then SELECT p[0] FROM t retrieves the X coordinate; UPDATE t SET p[1] = ... changes the Y coordinate. In the same way, a box or an lseg may be treated as an array of two points.
Network Address Type Functions <type>cidr</type> and <type>inet</type> Operators Operator Description Usage < Less than inet '192.168.1.5' < inet '192.168.1.6' <= Less than or equal inet '192.168.1.5' <= inet '192.168.1.5' = Equals inet '192.168.1.5' = inet '192.168.1.5' >= Greater or equal inet '192.168.1.5' >= inet '192.168.1.5' > Greater inet '192.168.1.5' > inet '192.168.1.4' <> Not equal inet '192.168.1.5' <> inet '192.168.1.4' << is contained within inet '192.168.1.5' << inet '192.168.1/24' <<= is contained within or equals inet '192.168.1/24' <<= inet '192.168.1/24' >> contains inet'192.168.1/24' >> inet '192.168.1.5' >>= contains or equals inet '192.168.1/24' >>= inet '192.168.1/24'
All of the operators for inet can be applied to cidr values as well. The operators <<, <<=, >>, >>= test for subnet inclusion: they consider only the network parts of the two addresses, ignoring any host part, and determine whether one network part is identical to or a subnet of the other. <type>cidr</type> and <type>inet</type> Functions Function Returns Description Example Result broadcast(inet) inet broadcast address for network broadcast('192.168.1.5/24') 192.168.1.255/24 host(inet) text extract IP address as text host('192.168.1.5/24') 192.168.1.5 masklen(inet) integer extract netmask length masklen('192.168.1.5/24') 24 set_masklen(inet,integer) inet set netmask length for inet value set_masklen('192.168.1.5/24',16) 192.168.1.5/16 netmask(inet) inet construct netmask for network netmask('192.168.1.5/24') 255.255.255.0 network(inet) cidr extract network part of address network('192.168.1.5/24') 192.168.1.0/24 text(inet) text extract IP address and masklen as text text(inet '192.168.1.5') 192.168.1.5/32 abbrev(inet) text extract abbreviated display as text abbrev(cidr '10.1.0.0/16') 10.1/16
All of the functions for inet can be applied to cidr values as well. The host(), text(), and abbrev() functions are primarily intended to offer alternative display formats. You can cast a text field to inet using normal casting syntax: inet(expression) or colname::inet. <type>macaddr</type> Functions Function Returns Description Example Result trunc(macaddr) macaddr set last 3 bytes to zero trunc(macaddr '12:34:56:78:90:ab') 12:34:56:00:00:00
The function trunc(macaddr) returns a MAC address with the last 3 bytes set to 0. This can be used to associate the remaining prefix with a manufacturer. The directory contrib/mac in the source distribution contains some utilities to create and maintain such an association table. The macaddr type also supports the standard relational operators (>, <=, etc.) for lexicographical ordering.
Sequence-Manipulation Functions sequences nextval currval setval Sequence Functions Function Returns Description nextval(text) bigint Advance sequence and return new value currval(text) bigint Return value most recently obtained with nextval setval(text,bigint) bigint Set sequence's current value setval(text,bigint,boolean) bigint Set sequence's current value and is_called flag
This section describes PostgreSQL's functions for operating on sequence objects. Sequence objects (also called sequence generators or just sequences) are special single-row tables created with CREATE SEQUENCE. A sequence object is usually used to generate unique identifiers for rows of a table. The sequence functions provide simple, multiuser-safe methods for obtaining successive sequence values from sequence objects. For largely historical reasons, the sequence to be operated on by a sequence-function call is specified by a text-string argument. To achieve some compatibility with the handling of ordinary SQL names, the sequence functions convert their argument to lower case unless the string is double-quoted. Thus nextval('foo') operates on sequence foo nextval('FOO') operates on sequence foo nextval('"Foo"') operates on sequence Foo The sequence name can be schema-qualified if necessary: nextval('myschema.foo') operates on myschema.foo nextval('"myschema".foo') same as above nextval('foo') searches search path for foo Of course, the text argument can be the result of an expression, not only a simple literal, which is occasionally useful. The available sequence functions are: nextval Advance the sequence object to its next value and return that value. This is done atomically: even if multiple server processes execute nextval concurrently, each will safely receive a distinct sequence value. currval Return the value most recently obtained by nextval for this sequence in the current server process. (An error is reported if nextval has never been called for this sequence in this process.) Notice that because this is returning a process-local value, it gives a predictable answer even if other server processes are executing nextval meanwhile. setval Reset the sequence object's counter value. The two-parameter form sets the sequence's last_value field to the specified value and sets its is_called field to true, meaning that the next nextval will advance the sequence before returning a value. In the three-parameter form, is_called may be set either true or false. If it's set to false, the next nextval will return exactly the specified value, and sequence advancement commences with the following nextval. For example, SELECT setval('foo', 42); Next nextval() will return 43 SELECT setval('foo', 42, true); Same as above SELECT setval('foo', 42, false); Next nextval() will return 42 The result returned by setval is just the value of its second argument. To avoid blocking of concurrent transactions that obtain numbers from the same sequence, a nextval operation is never rolled back; that is, once a value has been fetched it is considered used, even if the transaction that did the nextval later aborts. This means that aborted transactions may leave unused holes in the sequence of assigned values. setval operations are never rolled back, either. If a sequence object has been created with default parameters, nextval() calls on it will return successive values beginning with one. Other behaviors can be obtained by using special parameters in the CREATE SEQUENCE command; see its command reference page for more information.
Conditional Expressions case conditionals This section describes the SQL-compliant conditional expressions available in PostgreSQL. If your needs go beyond the capabilities of these conditional expressions you might want to consider writing a stored procedure in a more expressive programming language. CASE CASE WHEN condition THEN result WHEN ... ELSE result END The SQL CASE expression is a generic conditional expression, similar to if/else statements in other languages. CASE clauses can be used wherever an expression is valid. condition is an expression that returns a boolean result. If the result is true then the value of the CASE expression is result. If the result is false any subsequent WHEN clauses are searched in the same manner. If no WHEN condition is true then the value of the case expression is the result in the ELSE clause. If the ELSE clause is omitted and no condition matches, the result is null. An example: => SELECT * FROM test; a --- 1 2 3 => SELECT a, CASE WHEN a=1 THEN 'one' WHEN a=2 THEN 'two' ELSE 'other' END FROM test; a | case ---+------- 1 | one 2 | two 3 | other The data types of all the result expressions must be coercible to a single output type. See for more detail. CASE expression WHEN value THEN result WHEN ... ELSE result END This simple CASE expression is a specialized variant of the general form above. The expression is computed and compared to all the values in the WHEN clauses until one is found that is equal. If no match is found, the result in the ELSE clause (or a null value) is returned. This is similar to the switch statement in C. The example above can be written using the simple CASE syntax: => SELECT a, CASE a WHEN 1 THEN 'one' WHEN 2 THEN 'two' ELSE 'other' END FROM test; a | case ---+------- 1 | one 2 | two 3 | other COALESCE COALESCE(value , ...) The COALESCE function returns the first of its arguments that is not null. This is often useful to substitute a default value for null values when data is retrieved for display, for example: SELECT COALESCE(description, short_description, '(none)') ... NULLIF nullif NULLIF(value1, value2) The NULLIF function returns a null value if and only if value1 and value2 are equal. Otherwise it returns value1. This can be used to perform the inverse operation of the COALESCE example given above: SELECT NULLIF(value, '(none)') ... COALESCE and NULLIF are just shorthand for CASE expressions. They are actually converted into CASE expressions at a very early stage of processing, and subsequent processing thinks it is dealing with CASE. Thus an incorrect COALESCE or NULLIF usage may draw an error message that refers to CASE. Miscellaneous Functions Session Information Functions Name Return Type Description current_user name user name of current execution context session_user name session user name user name equivalent to current_user current_schema() name name of current schema current_schemas(boolean) name[] names of schemas in search path optionally including implicit schemas current_database() name name of current database
user current schema current search path current The session_user is the user that initiated a database connection; it is fixed for the duration of that connection. The current_user is the user identifier that is applicable for permission checking. Normally, it is equal to the session user, but it changes during the execution of functions with the attribute SECURITY DEFINER. In Unix parlance, the session user is the real user and the current user is the effective user. current_user, session_user, and user have special syntactic status in SQL: they must be called without trailing parentheses. Deprecated The function getpgusername() is an obsolete equivalent of current_user. current_schema returns the name of the schema that is at the front of the search path (or a null value if the search path is empty). This is the schema that will be used for any tables or other named objects that are created without specifying a target schema. current_schemas(boolean) returns an array of the names of all schemas presently in the search path. The boolean option determines whether or not implicitly included system schemas such as pg_catalog are included in the search path returned. search path changing at runtime The search path may be altered by a run-time setting. The command to use is SET SEARCH_PATH 'schema'[,'schema']... System Information Functions Name Return Type Description version text PostgreSQL version information
version version() returns a string describing the PostgreSQL server's version. Configuration Settings Information Functions Name Return Type Description current_setting(setting_name) text value of current setting set_config(setting_name, new_value, is_local) text new value of current setting
setting current setting set The current_setting is used to obtain the current value of the setting_name setting, as a query result. It is the equivalent to the SQL SHOW command. For example: select current_setting('DateStyle'); current_setting --------------------------------------- ISO with US (NonEuropean) conventions (1 row) set_config allows the setting_name setting to be changed to new_value. If is_local is set to true, the new value will only apply to the current transaction. If you want the new value to apply for the current session, use false instead. It is the equivalent to the SQL SET command. For example: select set_config('show_statement_stats','off','f'); set_config ------------ off (1 row) Access Privilege Inquiry Functions Name Return Type Description has_table_privilege(user, table, access) boolean does user have access to table has_table_privilege(table, access) boolean does current user have access to table has_database_privilege(user, database, access) boolean does user have access to database has_database_privilege(database, access) boolean does current user have access to database has_function_privilege(user, function, access) boolean does user have access to function has_function_privilege(function, access) boolean does current user have access to function has_language_privilege(user, language, access) boolean does user have access to language has_language_privilege(language, access) boolean does current user have access to language has_schema_privilege(user, schema, access) boolean does user have access to schema has_schema_privilege(schema, access) boolean does current user have access to schema
has_table_privilege has_database_privilege has_function_privilege has_language_privilege has_schema_privilege has_table_privilege checks whether a user can access a table in a particular way. The user can be specified by name or by ID (pg_user.usesysid), or if the argument is omitted current_user is assumed. The table can be specified by name or by OID. (Thus, there are actually six variants of has_table_privilege, which can be distinguished by the number and types of their arguments.) When specifying by name, the name can be schema-qualified if necessary. The desired access type is specified by a text string, which must evaluate to one of the values SELECT, INSERT, UPDATE, DELETE, RULE, REFERENCES, or TRIGGER. (Case of the string is not significant, however.) An example is: SELECT has_table_privilege('myschema.mytable', 'select'); has_database_privilege checks whether a user can access a database in a particular way. The possibilities for its arguments are analogous to has_table_privilege. The desired access type must evaluate to CREATE, TEMPORARY, or TEMP (which is equivalent to TEMPORARY). has_function_privilege checks whether a user can access a function in a particular way. The possibilities for its arguments are analogous to has_table_privilege. When specifying a function by a text string rather than by OID, the allowed input is the same as for the regprocedure data type. The desired access type must currently evaluate to EXECUTE. has_language_privilege checks whether a user can access a procedural language in a particular way. The possibilities for its arguments are analogous to has_table_privilege. The desired access type must currently evaluate to USAGE. has_schema_privilege checks whether a user can access a schema in a particular way. The possibilities for its arguments are analogous to has_table_privilege. The desired access type must evaluate to CREATE or USAGE. Schema Visibility Inquiry Functions Name Return Type Description pg_table_is_visible(tableOID) boolean is table visible in search path pg_type_is_visible(typeOID) boolean is type visible in search path pg_function_is_visible(functionOID) boolean is function visible in search path pg_operator_is_visible(operatorOID) boolean is operator visible in search path pg_opclass_is_visible(opclassOID) boolean is operator class visible in search path
pg_table_is_visible pg_type_is_visible pg_function_is_visible pg_operator_is_visible pg_opclass_is_visible pg_table_is_visible checks whether a table (or view, or any other kind of pg_class entry) is visible in the current schema search path. A table is said to be visible if its containing schema is in the search path and no table of the same name appears earlier in the search path. This is equivalent to the statement that the table can be referenced by name without explicit schema qualification. For example, to list the names of all visible tables: SELECT relname FROM pg_class WHERE pg_table_is_visible(oid); pg_type_is_visible, pg_function_is_visible, pg_operator_is_visible, and pg_opclass_is_visible perform the same sort of visibility check for types, functions, operators, and operator classes, respectively. For functions and operators, an object in the search path is visible if there is no object of the same name and argument data type(s) earlier in the path. For operator classes, both name and associated index access method are considered. All these functions require object OIDs to identify the object to be checked. If you want to test an object by name, it is convenient to use the OID alias types (regclass, regtype, regprocedure, or regoperator), for example SELECT pg_type_is_visible('myschema.widget'::regtype); Note that it would not make much sense to test an unqualified name in this way --- if the name can be recognized at all, it must be visible. Catalog Information Functions Name Return Type Description pg_get_viewdef(viewname) text Get CREATE VIEW command for view (deprecated) pg_get_viewdef(viewOID) text Get CREATE VIEW command for view pg_get_ruledef(ruleOID) text Get CREATE RULE command for rule pg_get_indexdef(indexOID) text Get CREATE INDEX command for index pg_get_constraintdef(constraintOID) text Get definition of a constraint pg_get_userbyid(userid) name Get user name given ID
pg_get_viewdef pg_get_ruledef pg_get_indexdef pg_get_constraintdef pg_get_userbyid These functions extract information from the system catalogs. pg_get_viewdef(), pg_get_ruledef(), pg_get_indexdef(), and pg_get_constraintdef() respectively reconstruct the creating command for a view, rule, index, or constraint. (Note that this is a decompiled reconstruction, not the verbatim text of the command.) At present pg_get_constraintdef() only works for foreign-key constraints. pg_get_userbyid() extracts a user's name given a usesysid value. Comment Information Functions Name Return Type Description obj_description(objectOID, tablename) text Get comment for a database object obj_description(objectOID) text Get comment for a database object (deprecated) col_description(tableOID, columnnumber) text Get comment for a table column
obj_description col_description These functions extract comments previously stored with the COMMENT command. A null value is returned if no comment can be found matching the specified parameters. The two-parameter form of obj_description() returns the comment for a database object specified by its OID and the name of the containing system catalog. For example, obj_description(123456,'pg_class') would retrieve the comment for a table with OID 123456. The one-parameter form of obj_description() requires only the object OID. It is now deprecated since there is no guarantee that OIDs are unique across different system catalogs; therefore, the wrong comment could be returned. col_description() returns the comment for a table column, which is specified by the OID of its table and its column number. obj_description() cannot be used for table columns since columns do not have OIDs of their own.
Aggregate Functions Author Written by Isaac Wilcox isaac@azartmedia.com on 2000-06-16 Aggregate functions compute a single result value from a set of input values. The special syntax considerations for aggregate functions are explained in . Consult the PostgreSQL Tutorial for additional introductory information. Aggregate Functions Function Description Notes avg(expression) the average (arithmetic mean) of all input values average function Finding the average value is available on the following data types: smallint, integer, bigint, real, double precision, numeric, interval. The result is of type numeric for any integer type input, double precision for floating-point input, otherwise the same as the input data type. count(*) number of input values The return value is of type bigint. count(expression) Counts the input values for which the value of expression is not null. The return value is of type bigint. max(expression) the maximum value of expression across all input values Available for all numeric, string, and date/time types. The result has the same type as the input expression. min(expression) the minimum value of expression across all input values Available for all numeric, string, and date/time types. The result has the same type as the input expression. stddev(expression) the sample standard deviation of the input values standard deviation Finding the standard deviation is available on the following data types: smallint, integer, bigint, real, double precision, numeric. The result is of type double precision for floating-point input, otherwise numeric. sum(expression) sum of expression across all input values Summation is available on the following data types: smallint, integer, bigint, real, double precision, numeric, interval. The result is of type bigint for smallint or integer input, numeric for bigint input, double precision for floating-point input, otherwise the same as the input data type. variance(expression) the sample variance of the input values variance The variance is the square of the standard deviation. The supported data types and result types are the same as for standard deviation.
It should be noted that except for COUNT, these functions return a null value when no rows are selected. In particular, SUM of no rows returns null, not zero as one might expect. COALESCE may be used to substitute zero for null when necessary.
Subquery Expressions exists in not in any all some subqueries This section describes the SQL-compliant subquery expressions available in PostgreSQL. All of the expression forms documented in this section return Boolean (true/false) results. EXISTS EXISTS ( subquery ) The argument of EXISTS is an arbitrary SELECT statement, or subquery. The subquery is evaluated to determine whether it returns any rows. If it returns at least one row, the result of EXISTS is TRUE; if the subquery returns no rows, the result of EXISTS is FALSE. The subquery can refer to variables from the surrounding query, which will act as constants during any one evaluation of the subquery. The subquery will generally only be executed far enough to determine whether at least one row is returned, not all the way to completion. It is unwise to write a subquery that has any side-effects (such as calling sequence functions); whether the side-effects occur or not may be difficult to predict. Since the result depends only on whether any rows are returned, and not on the contents of those rows, the output list of the subquery is normally uninteresting. A common coding convention is to write all EXISTS tests in the form EXISTS(SELECT 1 WHERE ...). There are exceptions to this rule however, such as subqueries that use INTERSECT. This simple example is like an inner join on col2, but it produces at most one output row for each tab1 row, even if there are multiple matching tab2 rows: SELECT col1 FROM tab1 WHERE EXISTS(SELECT 1 FROM tab2 WHERE col2 = tab1.col2); IN (scalar form) expression IN value, ...) The right-hand side of this form of IN is a parenthesized list of scalar expressions. The result is TRUE if the left-hand expression's result is equal to any of the right-hand expressions. This is a shorthand notation for expression = value1 OR expression = value2 OR ... Note that if the left-hand expression yields NULL, or if there are no equal right-hand values and at least one right-hand expression yields NULL, the result of the IN construct will be NULL, not FALSE. This is in accordance with SQL's normal rules for Boolean combinations of NULL values. This form of IN is not truly a subquery expression, but it seems best to document it in the same place as subquery IN. IN (subquery form) expression IN (subquery) The right-hand side of this form of IN is a parenthesized subquery, which must return exactly one column. The left-hand expression is evaluated and compared to each row of the subquery result. The result of IN is TRUE if any equal subquery row is found. The result is FALSE if no equal row is found (including the special case where the subquery returns no rows). Note that if the left-hand expression yields NULL, or if there are no equal right-hand values and at least one right-hand row yields NULL, the result of the IN construct will be NULL, not FALSE. This is in accordance with SQL's normal rules for Boolean combinations of NULL values. As with EXISTS, it's unwise to assume that the subquery will be evaluated completely. (expression, expres,) IN (subquery) The right-hand side of this form of IN is a parenthesized subquery, which must return exactly as many columns as there are expressions in the left-hand list. The left-hand expressions are evaluated and compared row-wise to each row of the subquery result. The result of IN is TRUE if any equal subquery row is found. The result is FALSE if no equal row is found (including the special case where the subquery returns no rows). As usual, null values in the expressions or subquery rows are combined per the normal rules of SQL Boolean expressions. Two rows are considered equal if all their corresponding members are non-null and equal; the rows are unequal if any corresponding members are non-null and unequal; otherwise the result of that row comparison is unknown (NULL). If all the row results are either unequal or NULL, with at least one NULL, then the result of IN is NULL. NOT IN (scalar form) expression NOT IN value, ...) The right-hand side of this form of NOT IN is a parenthesized list of scalar expressions. The result is TRUE if the left-hand expression's result is unequal to all of the right-hand expressions. This is a shorthand notation for expression <> value1 AND expression <> value2 AND ... Note that if the left-hand expression yields NULL, or if there are no equal right-hand values and at least one right-hand expression yields NULL, the result of the NOT IN construct will be NULL, not TRUE as one might naively expect. This is in accordance with SQL's normal rules for Boolean combinations of NULL values. x NOT IN y is equivalent to NOT (x IN y) in all cases. However, null values are much more likely to trip up the novice when working with NOT IN than when working with IN. It's best to express your condition positively if possible. NOT IN (subquery form) expression NOT IN (subquery) The right-hand side of this form of NOT IN is a parenthesized subquery, which must return exactly one column. The left-hand expression is evaluated and compared to each row of the subquery result. The result of NOT IN is TRUE if only unequal subquery rows are found (including the special case where the subquery returns no rows). The result is FALSE if any equal row is found. Note that if the left-hand expression yields NULL, or if there are no equal right-hand values and at least one right-hand row yields NULL, the result of the NOT IN construct will be NULL, not TRUE. This is in accordance with SQL's normal rules for Boolean combinations of NULL values. As with EXISTS, it's unwise to assume that the subquery will be evaluated completely. (expression, expres,) NOT IN (subquery) The right-hand side of this form of NOT IN is a parenthesized subquery, which must return exactly as many columns as there are expressions in the left-hand list. The left-hand expressions are evaluated and compared row-wise to each row of the subquery result. The result of NOT IN is TRUE if only unequal subquery rows are found (including the special case where the subquery returns no rows). The result is FALSE if any equal row is found. As usual, null values in the expressions or subquery rows are combined per the normal rules of SQL Boolean expressions. Two rows are considered equal if all their corresponding members are non-null and equal; the rows are unequal if any corresponding members are non-null and unequal; otherwise the result of that row comparison is unknown (NULL). If all the row results are either unequal or NULL, with at least one NULL, then the result of NOT IN is NULL. ANY expression oper ANY (subquery) expression oper SOME (subquery) The right-hand side of this form of ANY is a parenthesized subquery, which must return exactly one column. The left-hand expression is evaluated and compared to each row of the subquery result using the given operator, which must yield a Boolean result. The result of ANY is TRUE if any true result is obtained. The result is FALSE if no true result is found (including the special case where the subquery returns no rows). SOME is a synonym for ANY. IN is equivalent to = ANY. Note that if there are no successes and at least one right-hand row yields NULL for the operator's result, the result of the ANY construct will be NULL, not FALSE. This is in accordance with SQL's normal rules for Boolean combinations of NULL values. As with EXISTS, it's unwise to assume that the subquery will be evaluated completely. (expression, expres,optiona ANY (subquery) (expression, expres,optiona SOME (subquery) The right-hand side of this form of ANY is a parenthesized subquery, which must return exactly as many columns as there are expressions in the left-hand list. The left-hand expressions are evaluated and compared row-wise to each row of the subquery result, using the given operator. Presently, only = and <> operators are allowed in row-wise ANY queries. The result of ANY is TRUE if any equal or unequal row is found, respectively. The result is FALSE if no such row is found (including the special case where the subquery returns no rows). As usual, null values in the expressions or subquery rows are combined per the normal rules of SQL Boolean expressions. Two rows are considered equal if all their corresponding members are non-null and equal; the rows are unequal if any corresponding members are non-null and unequal; otherwise the result of that row comparison is unknown (NULL). If there is at least one NULL row result, then the result of ANY cannot be FALSE; it will be TRUE or NULL. ALL expression oper ALL (subquery) The right-hand side of this form of ALL is a parenthesized subquery, which must return exactly one column. The left-hand expression is evaluated and compared to each row of the subquery result using the given operator, which must yield a Boolean result. The result of ALL is TRUE if all rows yield TRUE (including the special case where the subquery returns no rows). The result is FALSE if any false result is found. NOT IN is equivalent to <> ALL. Note that if there are no failures but at least one right-hand row yields NULL for the operator's result, the result of the ALL construct will be NULL, not TRUE. This is in accordance with SQL's normal rules for Boolean combinations of NULL values. As with EXISTS, it's unwise to assume that the subquery will be evaluated completely. (expression, expression, ...) operator ALL (subquery) The right-hand side of this form of ALL is a parenthesized subquery, which must return exactly as many columns as there are expressions in the left-hand list. The left-hand expressions are evaluated and compared row-wise to each row of the subquery result, using the given operator. Presently, only = and <> operators are allowed in row-wise ALL queries. The result of ALL is TRUE if all subquery rows are equal or unequal, respectively (including the special case where the subquery returns no rows). The result is FALSE if any row is found to be unequal or equal, respectively. As usual, null values in the expressions or subquery rows are combined per the normal rules of SQL Boolean expressions. Two rows are considered equal if all their corresponding members are non-null and equal; the rows are unequal if any corresponding members are non-null and unequal; otherwise the result of that row comparison is unknown (NULL). If there is at least one NULL row result, then the result of ALL cannot be TRUE; it will be FALSE or NULL. Row-wise comparison (expression, expression, ...) operator (subquery) (expression, expression, ...) operator (expression expression, ...) The left-hand side is a list of scalar expressions. The right-hand side can be either a list of scalar expressions of the same length, or a parenthesized subquery, which must return exactly as many columns as there are expressions on the left-hand side. Furthermore, the subquery cannot return more than one row. (If it returns zero rows, the result is taken to be NULL.) The left-hand side is evaluated and compared row-wise to the single subquery result row, or to the right-hand expression list. Presently, only = and <> operators are allowed in row-wise comparisons. The result is TRUE if the two rows are equal or unequal, respectively. As usual, null values in the expressions or subquery rows are combined per the normal rules of SQL Boolean expressions. Two rows are considered equal if all their corresponding members are non-null and equal; the rows are unequal if any corresponding members are non-null and unequal; otherwise the result of the row comparison is unknown (NULL).