Functions and Operators Postgres 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 function 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. However, many other RDBMS packages provide a lot of the same or similar functions, and some of the ones provided in Postgres have in fact been inspired by other implementations. 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 boolean values; expressions like 1 < 2 < 3 are not valid (because there is no < operator to compare a boolean with 3).
Mathematical Functions and Operators 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.0 |/ Square root |/ 25.0 5.0 ||/ Cube root ||/ 27.0 3 ! Factorial 5 ! 120 !! Factorial (left operator) !! 5 120 @ Absolute value @ -5.0 5.0
Mathematical Functions Function Return Type Description Example Result abs(x) (same as argument type) absolute value abs(-17.4) 17.4 cbrt(double precision) double precision cube root cbrt(27.0) 9.0 ceil(numeric) numeric smallest integer not less than argument ceil(-42.8) -42 degrees(double precision) double precision convert radians to degrees degrees(0.5) 28.6478897565412 exp(double precision) double precision exponential function exp(1.0) 2.71828182845905 floor(numeric) numeric largest integer not greater than argument floor(-42.8) 43 ln(double precision) double precision natural logarithm ln(2.0) 0.693147180559945 log(double precision) double precision base 10 logarithm log(100.0) 2.0 log(base numeric, x numeric) numeric logarithm to specified base log(2.0, 64.0) 6.0 mod(y, x) (same as argument types) remainder (modulo) of the division y/x mod(9,4) 1 pi() double precision Pi constant pi() 3.14159265358979 pow(double precision, double precision) double precision raise a number to the specified exponent pow(9.0, 3.0) 729.0 radians(double precision) double precision convert degrees to radians radians(45.0) 0.785398163397448 random() double precision a pseudo-random value between 0.0 to 1.0 random() round(double precision) double precision round to nearest integer round(42.4) 42 round(value numeric, scale integer) numeric round to specified number of decimal places round(42.4382, 2) 42.44 sqrt(double precision) double precision square root sqrt(2.0) 1.4142135623731 trunc(double precision) double precision truncate (toward zero) trunc(42.8) 42 trunc(value numeric, scale integer) numeric truncate to specified number of decimal places round(42.4382, 2) 42.43
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. Many of these functions are implemented on top of the host system's C library and behavior in boundary cases could therefore vary depending on the operating system. Trigonometric Functions Function Description acos(x) inverse cosine asin(x) inverse sine atan(x) inverse tangent atan2(x, y) inverse tangent of y/x 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. 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 'Postgre' || 'SQL' PostgreSQL char_length(string) or character_length(string) integer length of string char_length('jose') 4 lower(string) text Convert string to lower case. lower('TOM') tom octet_length(string) integer number of bytes in string octet_length('jose') 4 position(substring in string) integer location of specified substring position('om' in 'Thomas') 3 substring(string from integer for integer) text extract substring substring('Thomas' from 2 for 3) 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 'xTomx') 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 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 initcap(text) text Converts first letter of each word (whitespace separated) to upper case. initcap('hello thomas') Hello Thomas 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, trim text) text Removes the longest string containing only characters from trim from the start of the string. ltrim('zzzytrim','xyz') trim repeat(text, integer) text Repeat text a number of times. repeat('Pg', 4) PgPgPgPg 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 strpos(string, substring) text Locates specified substring. (same as position(substring in string), but note the reversed argument order) strpos('high','ig') 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') 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, WIN1250 (CP1250) only.
Pattern Matching There are two separate approaches to pattern matching provided by Postgres: The SQL LIKE operator and POSIX-style regular expressions. If you have pattern matching needs that go beyond this, or want to make pattern-driven substitutions or translations, consider writing a user-defined function in Perl or Tcl. Pattern Matching with <function>LIKE</function> 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 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. On order to match a pattern anywhere within a string, the pattern must therefore start and end with a percent sign. In order to match a literal underscore or percent sign, the respective character in pattern must be preceded by the active escape character. The default escape character is the backslash but a different one may be selected by using the ESCAPE clause. When using the backslash as escape character in literal strings it must be doubled, because the backslash already has a special meaning in string literals. The keyword ILIKE can be used instead of LIKE to make the match case insensitive according to the active locale. This is a Postgres extension. The operator ~~ is equivalent to LIKE, ~~* corresponds to ILIKE. Finally, there are also !~~ and !~~* operators to represent NOT LIKE and NOT ILIKE. All of these are also Postgres-specific. POSIX Regular Expressions POSIX regular expressions provide a more powerful means for pattern matching than the LIKE function. 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. Unlike the LIKE operator, a regular expression also matches anywhere within a string, unless the regular expression is explicitly anchored to the beginning or end of the string. 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.*'
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). Obsolete REs are not available in Postgres. 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 a line), $ (matching the null string at the end of a line), 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 \. 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 multi-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 multi-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.
Formatting Functions Author Written by Karel Zak (zakkr@zf.jcu.cz) on 2000-01-24 The Postgres 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 datetypes. 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 format. Formatting Functions Function Returns Description Example to_char(timestamp, text) text convert timestamp to string to_char(timestamp 'now','HH12:MI:SS') to_char(int, text) text convert int4/int8 to string to_char(125, '999') to_char(float, text) text convert float4/float8 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) date convert string to timestamp to_timestamp('05 Dec 2000', 'DD Mon YYYY') to_number(text, text) numeric convert string to numeric to_number('12,454.8-', '99G999D9S')
Templates for date/time conversions Template 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) 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. year indicator (upper case) bc or b.c. or ad or a.d. year indicator (lower case) MONTH full upper case month name (9 chars) Month full mixed case month name (9 chars) month full lower case month name (9 chars) MON upper case abbreviated month name (3 chars) Mon abbreviated mixed case month name (3 chars) mon abbreviated lower case month name (3 chars) MM month (01-12) DAY full upper case day name (9 chars) Day full mixed case day name (9 chars) day full lower case day name (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 string - upper case tz timezone string - lower case
All templates allow the use of prefix and suffix modifiers. Modifiers are always valid for use in templates. The prefix FX is a global modifier only. Suffixes for templates for date/time to_char() Suffix Description Example FM fill mode prefix FMMonth TH upper ordinal number suffix DDTH th lower ordinal number suffix DDTH FX FiXed format global option (see below) FX Month DD Day SP spell mode (not yet implemented) DDSP
Usage notes: to_timestamp and to_date skip multiple blank space in converted 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 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 Postgres. Ordinary text is allowed in to_char templates but any string between double quotes is guaranteed that it will not be interpreted as a template keyword and it is also processed faster. (Example: '"Hello Year: "YYYY'). A double quote (") between quotation marks is skipped and is not parsed. If you want to have a double quote in the output you must preceed it with a double 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'). Templates for to_char(<replaceable>numeric</replaceable>) Template 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 numbers (not supported 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 preceed MI. PL, SG, and TH are Postgres extensions. 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. TH is a Postgres extension. 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, HH12:MI:SS') 'Tuesday , 05:39:18' to_char(now(),'FMDay, HH12:MI:SS') 'Tuesday, 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-decimal:"999" Post-decimal:" .999') 'Pre-decimal: 485 Post-decimal: .800' to_char(12,'99V999') ' 12000' to_char(12.4,'99V999') ' 12400' to_char(12.45, '99V9') ' 125'
Date/Time Functions The date/time functions provide a powerful set of tools for manipulating various date/time types. Date/Time Functions Function Returns Description Example abstime(timestamp) abstime convert to abstime abstime(timestamp 'now') age(timestamp) interval preserve months and years age(timestamp '1957-06-13') age(timestamp,timestamp) interval preserve months and years age('now', timestamp '1957-06-13') date_part(text,timestamp) float8 portion of date date_part('dow',timestamp 'now') date_part(text,interval) float8 portion of time date_part('hour',interval '4 hrs 3 mins') date_trunc(text,timestamp) timestamp truncate date date_trunc('month',abstime 'now') interval(reltime) interval convert to interval interval(reltime '4 hours') isfinite(timestamp) bool a finite time? isfinite(timestamp 'now') isfinite(interval) bool a finite time? isfinite(interval '4 hrs') reltime(interval) reltime convert to reltime reltime(interval '4 hrs') timestamp(date) timestamp convert to timestamp timestamp(date 'today') timestamp(date,time) timestamp convert to timestamp timestamp(timestamp '1998-02-24',time '23:07'); to_char(timestamp,text) text convert to string to_char(timestamp '1998-02-24','DD');
For the date_part and date_trunc functions, arguments can be `year', `month', `day', `hour', `minute', and `second', as well as the more specialized quantities `decade', `century', `millennium', `millisecond', and `microsecond'. date_part allows `dow' to return day of week, 'week' to return the ISO-defined week of year, and `epoch' to return seconds since 1970 (for timestamp) or 'epoch' to return total elapsed seconds (for interval).
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 '((0,0),(1,1))'::box + '(2.0,0)'::point - Translation '((0,0),(1,1))'::box - '(2.0,0)'::point * Scaling/rotation '((0,0),(1,1))'::box * '(2.0,0)'::point / Scaling/rotation '((0,0),(2,2))'::box / '(2.0,0)'::point # Intersection '((1,-1),(-1,1))' # '((1,1),(-1,-1))' # Number of points in polygon # '((1,0),(0,1),(-1,0))' ## Point of closest proximity '(0,0)'::point ## '((2,0),(0,2))'::lseg && Overlaps? '((0,0),(1,1))'::box && '((0,0),(2,2))'::box &< Overlaps to left? '((0,0),(1,1))'::box &< '((0,0),(2,2))'::box &> Overlaps to right? '((0,0),(3,3))'::box &> '((0,0),(2,2))'::box <-> Distance between '((0,0),1)'::circle <-> '((5,0),1)'::circle << Left of? '((0,0),1)'::circle << '((5,0),1)'::circle <^ Is below? '((0,0),1)'::circle <^ '((0,5),1)'::circle >> Is right of? '((5,0),1)'::circle >> '((0,0),1)'::circle >^ Is above? '((0,5),1)'::circle >^ '((0,0),1)'::circle ?# Intersects or overlaps '((-1,0),(1,0))'::lseg ?# '((-2,-2),(2,2))'::box; ?- Is horizontal? '(1,0)'::point ?- '(0,0)'::point ?-| Is perpendicular? '((0,0),(0,1))'::lseg ?-| '((0,0),(1,0))'::lseg @-@ Length or circumference @-@ '((0,0),(1,0))'::path ?| Is vertical? '(0,1)'::point ?| '(0,0)'::point ?|| Is parallel? '((-1,0),(1,0))'::lseg ?|| '((-1,2),(1,2))'::lseg @ Contained or on '(1,1)'::point @ '((0,0),2)'::circle @@ Center of @@ '((0,0),10)'::circle ~= Same as '((0,0),(1,1))'::polygon ~= '((1,1),(0,0))'::polygon
Geometric Functions Function Returns Description Example area(object) float8 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) float8 diameter of circle diameter(circle '((0,0),2.0)') height(box) float8 vertical size of box height(box '((0,0),(1,1))') isclosed(path) bool a closed path? isclosed(path '((0,0),(1,1),(2,0))') isopen(path) bool an open path? isopen(path '[(0,0),(1,1),(2,0)]') length(object) float8 length of item length(path '((-1,0),(1,0))') pclose(path) path convert path to closed popen(path '[(0,0),(1,1),(2,0)]') npoint(path) int4 number of points npoints(path '[(0,0),(1,1),(2,0)]') popen(path) path convert path to open path popen(path '((0,0),(1,1),(2,0))') radius(circle) float8 radius of circle radius(circle '((0,0),2.0)') width(box) float8 horizontal size width(box '((0,0),(1,1))')
Geometric Type Conversion Functions Function Returns Description Example box(circle) box circle to box box('((0,0),2.0)'::circle) box(point,point) box points to box box('(0,0)'::point,'(1,1)'::point) box(polygon) box polygon to box box('((0,0),(1,1),(2,0))'::polygon) circle(box) circle to circle circle('((0,0),(1,1))'::box) circle(point,float8) circle point to circle circle('(0,0)'::point,2.0) lseg(box) lseg box diagonal to lseg lseg('((-1,0),(1,0))'::box) lseg(point,point) lseg points to lseg lseg('(-1,0)'::point,'(1,0)'::point) path(polygon) point polygon to path path('((0,0),(1,1),(2,0))'::polygon) point(circle) point center point('((0,0),2.0)'::circle) point(lseg,lseg) point intersection point('((-1,0),(1,0))'::lseg, '((-2,-2),(2,2))'::lseg) point(polygon) point center point('((0,0),(1,1),(2,0))'::polygon) polygon(box) polygon 12 point polygon polygon('((0,0),(1,1))'::box) polygon(circle) polygon 12-point polygon polygon('((0,0),2.0)'::circle) polygon(npts,circle) polygon npts polygon polygon(12,'((0,0),2.0)'::circle) polygon(path) polygon path to polygon polygon('((0,0),(1,1),(2,0))'::path)
Network Address Type Functions <type>cidr</> and <type>inet</> 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</> and <type>inet</> 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 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/24 text(inet) text extract IP address and masklen as text text(inet '192.168.1.5') 192.168.1.5/32
All of the functions for inet can be applied to cidr values as well. The host() and text() functions are primarily intended to offer alternative display formats. <type>macaddr</> 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.
Conditional Expressions This section descibes the SQL-compliant conditional expressions available in Postgres. 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 whereever 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 possible result expressions must match. 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 NULL) 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(value1, value2) The NULLIF function returns NULL 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)') ... Miscellaneous Functions</> <table> <title>Miscellaneous Functions</> <tgroup cols="3"> <thead> <row><entry>Name</> <entry>Return type</> <entry>Description</></row> </thead> <tbody> <row> <entry>current_user</> <entry>name</> <entry>user name of current execution context</> </row> <row> <entry>session_user</> <entry>name</> <entry>session user name</> </row> <row> <entry>user</> <entry>name</> <entry>equivalent to <function>current_user</></> </row> </tbody> </tgroup> </table> <para> The <function>session_user</> is the user that initiated a database connection and is fixed for the duration of that connection. The <function>current_user</> is the user identifier that is applicable for permission checking. Currently it is always equal to the session user, but in the future there might be <quote>setuid</> functions and other facilities to allow the current user to change temporarily. In Unix parlance, the session user is the <quote>real user</> and the current user is the <quote>effective user</>. </para> <para> Note that these functions have special syntactic status in <acronym>SQL</>; they must be called without trailing parentheses. </para> <note> <title>Deprecated</> <para> The function <function>getpgusername()</> is an obsolete equivalent of <function>current_user</>. </para> </note> </sect1> <sect1 id="functions-aggregate"> <title>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 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 integer. COUNT(expression) Counts the input values for which the value of expression is not NULL. 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 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 numeric for any integer type input, double precision for floating point input, otherwise the same as the input data type. VARIANCE(expression) the sample variance of the input values The variance is the square of the standard deviation. The supported data types are the same.
It should be noted that except for COUNT, these functions return NULL when no rows are selected. In particular, SUM of no rows returns NULL, not zero as one might expect.