Functions Describes the built-in functions available in Postgres. Many data types have functions available for conversion to other related types. In addition, there are some type-specific functions. Some functions are also available through operators and may be documented as operators only. SQL Functions SQL functions are constructs defined by the SQL92 standard which have function-like syntax but which can not be implemented as simple functions. SQL Functions Function Returns Description Example COALESCE(list) non-NULL return first non-NULL value in list COALESCE(rle, c2 + 5, 0) NULLIF(input,value) input or NULL return NULL if input = value, else input NULLIF(c1, 'N/A') CASE WHEN expr THEN expr [...] ELSE expr END expr return expression for first true WHEN clause CASE WHEN c1 = 1 THEN 'match' ELSE 'no match' END
Mathematical Functions Mathematical Functions Function Returns Description Example abs(float8) float8 absolute value abs(-17.4) sqrt(float8) float8 square root sqrt(2.0) exp(float8) float8 raise e to the specified exponent exp(2.0) ln(float8) float8 natural logarithm ln(2.0) log(float8) float8 base 10 logarithm log(2.0) pow(float8,float8) float8 raise a number to the specified exponent pow(2.0, 16.0) round(float8) float8 round to nearest integer round(42.4) trunc(float8) float8 truncate (towards zero) trunc(42.4) float(int) float8 convert integer to floating point float(2) float4(int) float4 convert integer to floating point float4(2) integer(float) int convert floating point to integer integer(2.0)
Most of the functions listed for FLOAT8 are also available for type NUMERIC.
String Functions SQL92 defines string functions with specific syntax. Some of these are implemented using other Postgres functions. The supported string types for SQL92 are char, varchar, and text. <acronym>SQL92</acronym> String Functions Function Returns Description Example char_length(string) int4 length of string char_length('jose') character_length(string) int4 length of string char_length('jose') lower(string) string convert string to lower case lower('TOM') octet_length(string) int4 storage length of string octet_length('jose') position(string in string) int4 location of specified substring position('o' in 'Tom') substring(string [from int] [for int]) string extract specified substring substring('Tom' from 2 for 2) trim([leading|trailing|both] [string] from string) string trim characters from string trim(both 'x' from 'xTomx') upper(text) text convert text to upper case upper('tom')
Many additional string functions are available for text, varchar(), and char() types. Some are used internally to implement the SQL92 string functions listed above. String Functions Function Returns Description Example char(text) char convert text to char type char('text string') char(varchar) char convert varchar to char type char(varchar 'varchar string') initcap(text) text first letter of each word to upper case initcap('thomas') lpad(text,int,text) text left pad string to specified length lpad('hi',4,'??') ltrim(text,text) text left trim characters from text ltrim('xxxxtrim','x') textpos(text,text) text locate specified substring position('high','ig') rpad(text,int,text) text right pad string to specified length rpad('hi',4,'x') rtrim(text,text) text right trim characters from text rtrim('trimxxxx','x') substr(text,int[,int]) text extract specified substring substr('hi there',3,5) text(char) text convert char to text type text('char string') text(varchar) text convert varchar to text type text(varchar 'varchar string') translate(text,from,to) text convert character in string translate('12345', '1', 'a') varchar(char) varchar convert char to varchar type varchar('char string') varchar(text) varchar convert text to varchar type varchar('text string')
Most functions explicitly defined for text will work for char() and varchar() arguments.
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') timestamp(abstime) timestamp convert to timestamp timestamp(abstime 'now') timestamp(date) timestamp convert to timestamp timestamp(date 'today') timestamp(date,time) timestamp convert to timestamp timestamp(timestamp '1998-02-24',time '23:07'); 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') isfinite(abstime) bool a finite time? isfinite(abstime 'now') 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') interval(reltime) interval convert to interval interval(reltime '4 hours')
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', `millenium', `millisecond', and `microsecond'. date_part allows `dow' to return day of week and `epoch' to return seconds since 1970 (for timestamp) or 'epoch' to return total elapsed seconds (for interval).
Formatting Functions Author Written by Karel Zak on 2000-01-24. The Postgres formatting functions provide a powerful set of tools for converting various datetypes (date/time, int, float, numeric) to formatted strings and for converting from formatted strings to specific datetypes. The second argument for all formatting functions is a template to be used for the conversion. 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) MI minute (00-59) SS second (00-59) SSSS seconds past midnight (0-86399) 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 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 WW week number of year CC century (2 digits) J Julian Day (days since January 1, 4712 BC) Q quarter RM month in Roman Numerals (I-XII; I=JAN)
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 blank space if the FX option is not use. FX Must be specified as the first item in the template. '\' - must be use as double \\, example '\\HH\\MI\\SS' '"' - string between a quotation marks is skipen and not is parsed. If you want write '"' to output you must use \\", example '\\"YYYY Month\\"'. text - the PostgreSQL's to_char() support text without '"', but string between a quotation marks is fastly and you have guarantee, that a text not will interpreted as a keyword (format-picture), exapmle '"Hello Year: "YYYY'. 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 (use locales) L currency symbol (use locales) D decimal point (use locales) G group separator (use locales) MI minus sign on specified position (if number < 0) PL plus sign on specified position (if number > 0) SG plus/minus sign on specified position RN roman numeral (input between 1 and 3999) TH or th convert to ordinal number V Shift n digits (see notes) EEEE science numbers. Now not supported.
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 preceeds 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'
Geometric Functions The geometric types point, box, lseg, line, path, polygon, and circle have a large set of native support functions. Geometric Functions Function Returns Description Example area(object) float8 area of circle, ... area(box '((0,0),(1,1))') box(box,box) box boxes to intersection box box(box '((0,0),(1,1))',box '((0.5,0.5),(2,2))') center(object) point center of circle, ... 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 line segment, ... length(path '((-1,0),(1,0))') length(path) float8 length of path length(path '((0,0),(1,1),(2,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 convert circle to box box('((0,0),2.0)'::circle) box(point,point) box convert points to box box('(0,0)'::point,'(1,1)'::point) box(polygon) box convert polygon to box box('((0,0),(1,1),(2,0))'::polygon) circle(box) circle convert to circle circle('((0,0),(1,1))'::box) circle(point,float8) circle convert to circle circle('(0,0)'::point,2.0) lseg(box) lseg convert diagonal to lseg lseg('((-1,0),(1,0))'::box) lseg(point,point) lseg convert to lseg lseg('(-1,0)'::point,'(1,0)'::point) path(polygon) point convert to path path('((0,0),(1,1),(2,0))'::polygon) point(circle) point convert to point (center) point('((0,0),2.0)'::circle) point(lseg,lseg) point convert to point (intersection) point('((-1,0),(1,0))'::lseg, '((-2,-2),(2,2))'::lseg) point(polygon) point center of polygon point('((0,0),(1,1),(2,0))'::polygon) polygon(box) polygon convert to polygon with 12 points polygon('((0,0),(1,1))'::box) polygon(circle) polygon convert to 12-point polygon polygon('((0,0),2.0)'::circle) polygon(npts,circle) polygon convert to npts polygon polygon(12,'((0,0),2.0)'::circle) polygon(path) polygon convert to polygon polygon('((0,0),(1,1),(2,0))'::path)
Geometric Upgrade Functions Function Returns Description Example isoldpath(path) path test path for pre-v6.1 form isoldpath('(1,3,0,0,1,1,2,0)'::path) revertpoly(polygon) polygon convert pre-v6.1 polygon revertpoly('((0,0),(1,1),(2,0))'::polygon) upgradepath(path) path convert pre-v6.1 path upgradepath('(1,3,0,0,1,1,2,0)'::path) upgradepoly(polygon) polygon convert pre-v6.1 polygon upgradepoly('(0,1,2,0,1,0)'::polygon)
IP V4 Functions <productname>Postgres</productname>IP V4 Functions Function Returns Description Example broadcast(cidr) text construct broadcast address as text broadcast('192.168.1.5/24') broadcast(inet) text construct broadcast address as text broadcast('192.168.1.5/24') host(inet) text extract host address as text host('192.168.1.5/24') masklen(cidr) int4 calculate netmask length masklen('192.168.1.5/24') masklen(inet) int4 calculate netmask length masklen('192.168.1.5/24') netmask(inet) text construct netmask as text netmask('192.168.1.5/24')