mirror of https://github.com/postgres/postgres
from datatype.sgml into separate files. Add type conversion information. Format historical release notes.REL6_4
parent
febe53d813
commit
ba3a99f193
@ -0,0 +1,616 @@ |
||||
<Chapter> |
||||
<Title>Functions</Title> |
||||
|
||||
<Abstract> |
||||
<Para> |
||||
Describes the built-in functions available in <ProductName>Postgres</ProductName>. |
||||
</Para> |
||||
</Abstract> |
||||
|
||||
<Para> |
||||
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. |
||||
</Para> |
||||
|
||||
<sect1> |
||||
<title>Mathematical Functions</title> |
||||
|
||||
<Para> |
||||
<TABLE TOCENTRY="1"> |
||||
<TITLE>Mathematical Functions</TITLE> |
||||
<TGROUP COLS="4"> |
||||
<THEAD> |
||||
<ROW> |
||||
<ENTRY>Function</ENTRY> |
||||
<ENTRY>Returns</ENTRY> |
||||
<ENTRY>Description</ENTRY> |
||||
<ENTRY>Example</ENTRY> |
||||
</ROW> |
||||
</THEAD> |
||||
<TBODY> |
||||
<ROW> |
||||
<ENTRY> dexp(float8) </ENTRY> |
||||
<ENTRY> float8 </ENTRY> |
||||
<ENTRY> raise e to the specified exponent </ENTRY> |
||||
<ENTRY> dexp(2.0) </ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> dpow(float8,float8) </ENTRY> |
||||
<ENTRY> float8 </ENTRY> |
||||
<ENTRY> raise a number to the specified exponent </ENTRY> |
||||
<ENTRY> dpow(2.0, 16.0) </ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> float(int) </ENTRY> |
||||
<ENTRY> float8 </ENTRY> |
||||
<ENTRY> convert integer to floating point </ENTRY> |
||||
<ENTRY> float(2) </ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> float4(int) </ENTRY> |
||||
<ENTRY> float4 </ENTRY> |
||||
<ENTRY> convert integer to floating point </ENTRY> |
||||
<ENTRY> float4(2) </ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> integer(float) </ENTRY> |
||||
<ENTRY> int </ENTRY> |
||||
<ENTRY> convert floating point to integer </ENTRY> |
||||
<ENTRY> integer(2.0) </ENTRY> |
||||
</ROW> |
||||
</TBODY> |
||||
</TGROUP> |
||||
</TABLE> |
||||
</Para> |
||||
|
||||
<sect1> |
||||
<title>String Functions</title> |
||||
|
||||
<Para> |
||||
SQL92 defines string functions with specific syntax. Some of these |
||||
are implemented using other <ProductName>Postgres</ProductName> functions. |
||||
</Para> |
||||
|
||||
<Para> |
||||
<TABLE TOCENTRY="1"> |
||||
<TITLE><Acronym>SQL92</Acronym> Text Functions</TITLE> |
||||
<TGROUP COLS="4"> |
||||
<THEAD> |
||||
<ROW> |
||||
<ENTRY>Function</ENTRY> |
||||
<ENTRY>Returns</ENTRY> |
||||
<ENTRY>Description</ENTRY> |
||||
<ENTRY>Example</ENTRY> |
||||
</ROW> |
||||
</THEAD> |
||||
<TBODY> |
||||
<ROW> |
||||
<ENTRY> position(text in text) </ENTRY> |
||||
<ENTRY> int4 </ENTRY> |
||||
<ENTRY> location of specified substring </ENTRY> |
||||
<ENTRY> position('o' in 'Tom') </ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> substring(text [from int] [for int]) </ENTRY> |
||||
<ENTRY> text </ENTRY> |
||||
<ENTRY> extract specified substring </ENTRY> |
||||
<ENTRY> substring('Tom' from 2 for 2) </ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> trim([leading|trailing|both] [text] from text) </ENTRY> |
||||
<ENTRY> text </ENTRY> |
||||
<ENTRY> trim characters from text </ENTRY> |
||||
<ENTRY> trim(both 'x' from 'xTomx') </ENTRY> |
||||
</ROW> |
||||
</TBODY> |
||||
</TGROUP> |
||||
</TABLE> |
||||
</Para> |
||||
|
||||
<Para> |
||||
Many string functions are available for text, varchar(), and char() types. |
||||
Some are used internally to implement the SQL92 string functions listed above. |
||||
</Para> |
||||
|
||||
<Para> |
||||
<TABLE TOCENTRY="1"> |
||||
<TITLE>String Functions</TITLE> |
||||
<TGROUP COLS="4"> |
||||
<THEAD> |
||||
<ROW> |
||||
<ENTRY>Function</ENTRY> |
||||
<ENTRY>Returns</ENTRY> |
||||
<ENTRY>Description</ENTRY> |
||||
<ENTRY>Example</ENTRY> |
||||
</ROW> |
||||
</THEAD> |
||||
<TBODY> |
||||
<ROW> |
||||
<ENTRY> char(text) </ENTRY> |
||||
<ENTRY> char </ENTRY> |
||||
<ENTRY> convert text to char type </ENTRY> |
||||
<ENTRY> char('text string') </ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> char(varchar) </ENTRY> |
||||
<ENTRY> char </ENTRY> |
||||
<ENTRY> convert varchar to char type </ENTRY> |
||||
<ENTRY> char(varchar 'varchar string') </ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> lower(text) </ENTRY> |
||||
<ENTRY> text </ENTRY> |
||||
<ENTRY> convert text to lower case </ENTRY> |
||||
<ENTRY> lower('TOM') </ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> lpad(text,int,text) </ENTRY> |
||||
<ENTRY> text </ENTRY> |
||||
<ENTRY> left pad string to specified length </ENTRY> |
||||
<ENTRY> lpad('hi',4,'??') </ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> ltrim(text,text) </ENTRY> |
||||
<ENTRY> text </ENTRY> |
||||
<ENTRY> left trim characters from text </ENTRY> |
||||
<ENTRY> ltrim('xxxxtrim','x') </ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> position(text,text) </ENTRY> |
||||
<ENTRY> text </ENTRY> |
||||
<ENTRY> extract specified substring </ENTRY> |
||||
<ENTRY> position('high','ig') </ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> rpad(text,int,text) </ENTRY> |
||||
<ENTRY> text </ENTRY> |
||||
<ENTRY> right pad string to specified length </ENTRY> |
||||
<ENTRY> rpad('hi',4,'x') </ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> rtrim(text,text) </ENTRY> |
||||
<ENTRY> text </ENTRY> |
||||
<ENTRY> right trim characters from text </ENTRY> |
||||
<ENTRY> rtrim('trimxxxx','x') </ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> substr(text,int[,int]) </ENTRY> |
||||
<ENTRY> text </ENTRY> |
||||
<ENTRY> extract specified substring </ENTRY> |
||||
<ENTRY> substr('hi there',3,5) </ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> text(char) </ENTRY> |
||||
<ENTRY> text </ENTRY> |
||||
<ENTRY> convert char to text type </ENTRY> |
||||
<ENTRY> text('char string') </ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> text(varchar) </ENTRY> |
||||
<ENTRY> text </ENTRY> |
||||
<ENTRY> convert varchar to text type </ENTRY> |
||||
<ENTRY> text(varchar 'varchar string') </ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> varchar(char) </ENTRY> |
||||
<ENTRY> varchar </ENTRY> |
||||
<ENTRY> convert char to varchar type </ENTRY> |
||||
<ENTRY> varchar('char string') </ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> varchar(text) </ENTRY> |
||||
<ENTRY> varchar </ENTRY> |
||||
<ENTRY> convert text to varchar type </ENTRY> |
||||
<ENTRY> varchar('text string') </ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> upper(text) </ENTRY> |
||||
<ENTRY> text </ENTRY> |
||||
<ENTRY> convert text to upper case </ENTRY> |
||||
<ENTRY> upper('tom') </ENTRY> |
||||
</ROW> |
||||
</TBODY> |
||||
</TGROUP> |
||||
</TABLE> |
||||
</Para> |
||||
|
||||
<para> |
||||
Most functions explicitly defined for text will work for char() and varchar() arguments. |
||||
</para> |
||||
|
||||
<sect1> |
||||
<title>Date/Time Functions</title> |
||||
|
||||
<para> |
||||
The date/time functions provide a powerful set of tools for manipulating various date/time types. |
||||
</para> |
||||
|
||||
<Para> |
||||
<TABLE TOCENTRY="1"> |
||||
<TITLE>Date/Time Functions</TITLE> |
||||
<TGROUP COLS="4"> |
||||
<THEAD> |
||||
<ROW> |
||||
<ENTRY>Function</ENTRY> |
||||
<ENTRY>Returns</ENTRY> |
||||
<ENTRY>Description</ENTRY> |
||||
<ENTRY>Example</ENTRY> |
||||
</ROW> |
||||
</THEAD> |
||||
<TBODY> |
||||
<ROW> |
||||
<ENTRY> abstime(datetime) </ENTRY> |
||||
<ENTRY> abstime </ENTRY> |
||||
<ENTRY> convert to abstime </ENTRY> |
||||
<ENTRY> abstime('now'::datetime) </ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> age(datetime,datetime) </ENTRY> |
||||
<ENTRY> timespan </ENTRY> |
||||
<ENTRY> span preserving months and years </ENTRY> |
||||
<ENTRY> age('now','1957-06-13'::datetime) </ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> datetime(abstime) </ENTRY> |
||||
<ENTRY> datetime </ENTRY> |
||||
<ENTRY> convert to datetime </ENTRY> |
||||
<ENTRY> datetime('now'::abstime) </ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> datetime(date) </ENTRY> |
||||
<ENTRY> datetime </ENTRY> |
||||
<ENTRY> convert to datetime </ENTRY> |
||||
<ENTRY> datetime('today'::date) </ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> datetime(date,time) </ENTRY> |
||||
<ENTRY> datetime </ENTRY> |
||||
<ENTRY> convert to datetime </ENTRY> |
||||
<ENTRY> datetime('1998-02-24'::datetime, '23:07'::time); </ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> date_part(text,datetime) </ENTRY> |
||||
<ENTRY> float8 </ENTRY> |
||||
<ENTRY> specified portion of date field </ENTRY> |
||||
<ENTRY> date_part('dow','now'::datetime) </ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> date_part(text,timespan) </ENTRY> |
||||
<ENTRY> float8 </ENTRY> |
||||
<ENTRY> specified portion of time field </ENTRY> |
||||
<ENTRY> date_part('hour','4 hrs 3 mins'::timespan) </ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> date_trunc(text,datetime) </ENTRY> |
||||
<ENTRY> datetime </ENTRY> |
||||
<ENTRY> truncate date at specified units </ENTRY> |
||||
<ENTRY> date_trunc('month','now'::abstime) </ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> isfinite(abstime) </ENTRY> |
||||
<ENTRY> bool </ENTRY> |
||||
<ENTRY> TRUE if this is a finite time </ENTRY> |
||||
<ENTRY> isfinite('now'::abstime) </ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> isfinite(datetime) </ENTRY> |
||||
<ENTRY> bool </ENTRY> |
||||
<ENTRY> TRUE if this is a finite time </ENTRY> |
||||
<ENTRY> isfinite('now'::datetime) </ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> isfinite(timespan) </ENTRY> |
||||
<ENTRY> bool </ENTRY> |
||||
<ENTRY> TRUE if this is a finite time </ENTRY> |
||||
<ENTRY> isfinite('4 hrs'::timespan) </ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> reltime(timespan) </ENTRY> |
||||
<ENTRY> reltime </ENTRY> |
||||
<ENTRY> convert to reltime </ENTRY> |
||||
<ENTRY> reltime('4 hrs'::timespan) </ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> timespan(reltime) </ENTRY> |
||||
<ENTRY> timespan </ENTRY> |
||||
<ENTRY> convert to timespan </ENTRY> |
||||
<ENTRY> timespan('4 hours'::reltime) </ENTRY> |
||||
</ROW> |
||||
</TBODY> |
||||
</TGROUP> |
||||
</TABLE> |
||||
</Para> |
||||
|
||||
<Para> |
||||
For the |
||||
<Function>date_part</Function> and <Function>date_trunc</Function> |
||||
functions, arguments can be |
||||
`year', `month', `day', `hour', `minute', and `second', |
||||
as well as the more specialized quantities |
||||
`decade', `century', `millenium', `millisecond', and `microsecond'. |
||||
<Function>date_part</Function> allows `dow' |
||||
to return day of week and `epoch' to return seconds since 1970 (for <Type>datetime</Type>) |
||||
or 'epoch' to return total elapsed seconds (for <Type>timespan</Type>). |
||||
</Para> |
||||
|
||||
<sect1> |
||||
<title>Geometric Functions</title> |
||||
|
||||
<para> |
||||
The geometric types point, box, lseg, line, path, polygon, and circle have a large set of native |
||||
support functions. |
||||
</para> |
||||
|
||||
<Para> |
||||
<TABLE TOCENTRY="1"> |
||||
<TITLE>Geometric Functions</TITLE> |
||||
<TGROUP COLS="4"> |
||||
<THEAD> |
||||
<ROW> |
||||
<ENTRY>Function</ENTRY> |
||||
<ENTRY>Returns</ENTRY> |
||||
<ENTRY>Description</ENTRY> |
||||
<ENTRY>Example</ENTRY> |
||||
</ROW> |
||||
</THEAD> |
||||
<TBODY> |
||||
<ROW> |
||||
<ENTRY> area(box) </ENTRY> |
||||
<ENTRY> float8 </ENTRY> |
||||
<ENTRY> area of box </ENTRY> |
||||
<ENTRY> area('((0,0),(1,1))'::box) </ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> area(circle) </ENTRY> |
||||
<ENTRY> float8 </ENTRY> |
||||
<ENTRY> area of circle </ENTRY> |
||||
<ENTRY> area('((0,0),2.0)'::circle) </ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> box(box,box) </ENTRY> |
||||
<ENTRY> box </ENTRY> |
||||
<ENTRY> boxes to intersection box </ENTRY> |
||||
<ENTRY> box('((0,0),(1,1))','((0.5,0.5),(2,2))') </ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> center(box) </ENTRY> |
||||
<ENTRY> point </ENTRY> |
||||
<ENTRY> center of object </ENTRY> |
||||
<ENTRY> center('((0,0),(1,2))'::box) </ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> center(circle) </ENTRY> |
||||
<ENTRY> point </ENTRY> |
||||
<ENTRY> center of object </ENTRY> |
||||
<ENTRY> center('((0,0),2.0)'::circle) </ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> diameter(circle) </ENTRY> |
||||
<ENTRY> float8 </ENTRY> |
||||
<ENTRY> diameter of circle </ENTRY> |
||||
<ENTRY> diameter('((0,0),2.0)'::circle) </ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> height(box) </ENTRY> |
||||
<ENTRY> float8 </ENTRY> |
||||
<ENTRY> vertical size of box </ENTRY> |
||||
<ENTRY> height('((0,0),(1,1))'::box) </ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> isclosed(path) </ENTRY> |
||||
<ENTRY> bool </ENTRY> |
||||
<ENTRY> TRUE if this is a closed path </ENTRY> |
||||
<ENTRY> isclosed('((0,0),(1,1),(2,0))'::path) </ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> isopen(path) </ENTRY> |
||||
<ENTRY> bool </ENTRY> |
||||
<ENTRY> TRUE if this is an open path </ENTRY> |
||||
<ENTRY> isopen('[(0,0),(1,1),(2,0)]'::path) </ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> length(lseg) </ENTRY> |
||||
<ENTRY> float8 </ENTRY> |
||||
<ENTRY> length of line segment </ENTRY> |
||||
<ENTRY> length('((-1,0),(1,0))'::lseg) </ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> length(path) </ENTRY> |
||||
<ENTRY> float8 </ENTRY> |
||||
<ENTRY> length of path </ENTRY> |
||||
<ENTRY> length('((0,0),(1,1),(2,0))'::path) </ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> pclose(path) </ENTRY> |
||||
<ENTRY> path </ENTRY> |
||||
<ENTRY> convert path to closed variant </ENTRY> |
||||
<ENTRY> popen('[(0,0),(1,1),(2,0)]'::path) </ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> point(lseg,lseg) </ENTRY> |
||||
<ENTRY> point </ENTRY> |
||||
<ENTRY> convert to point (intersection) </ENTRY> |
||||
<ENTRY> point('((-1,0),(1,0))'::lseg,'((-2,-2),(2,2))'::lseg) </ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> points(path) </ENTRY> |
||||
<ENTRY> int4 </ENTRY> |
||||
<ENTRY> number of points in path </ENTRY> |
||||
<ENTRY> points('[(0,0),(1,1),(2,0)]'::path) </ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> popen(path) </ENTRY> |
||||
<ENTRY> path </ENTRY> |
||||
<ENTRY> convert path to open variant </ENTRY> |
||||
<ENTRY> popen('((0,0),(1,1),(2,0))'::path) </ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> radius(circle) </ENTRY> |
||||
<ENTRY> float8 </ENTRY> |
||||
<ENTRY> radius of circle </ENTRY> |
||||
<ENTRY> radius('((0,0),2.0)'::circle) </ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> width(box) </ENTRY> |
||||
<ENTRY> float8 </ENTRY> |
||||
<ENTRY> horizontal size of box </ENTRY> |
||||
<ENTRY> width('((0,0),(1,1))'::box) </ENTRY> |
||||
</ROW> |
||||
</TBODY> |
||||
</TGROUP> |
||||
</TABLE> |
||||
</Para> |
||||
|
||||
<Para> |
||||
<TABLE TOCENTRY="1"> |
||||
<TITLE>Geometric Type Conversion Functions</TITLE> |
||||
<TGROUP COLS="4"> |
||||
<THEAD> |
||||
<ROW> |
||||
<ENTRY>Function</ENTRY> |
||||
<ENTRY>Returns</ENTRY> |
||||
<ENTRY>Description</ENTRY> |
||||
<ENTRY>Example</ENTRY> |
||||
</ROW> |
||||
</THEAD> |
||||
<TBODY> |
||||
<ROW> |
||||
<ENTRY> box(circle) </ENTRY> |
||||
<ENTRY> box </ENTRY> |
||||
<ENTRY> convert circle to box </ENTRY> |
||||
<ENTRY> box('((0,0),2.0)'::circle) </ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> box(point,point) </ENTRY> |
||||
<ENTRY> box </ENTRY> |
||||
<ENTRY> convert points to box </ENTRY> |
||||
<ENTRY> box('(0,0)'::point,'(1,1)'::point) </ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> box(polygon) </ENTRY> |
||||
<ENTRY> box </ENTRY> |
||||
<ENTRY> convert polygon to box </ENTRY> |
||||
<ENTRY> box('((0,0),(1,1),(2,0))'::polygon) </ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> circle(box) </ENTRY> |
||||
<ENTRY> circle </ENTRY> |
||||
<ENTRY> convert to circle </ENTRY> |
||||
<ENTRY> circle('((0,0),(1,1))'::box) </ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> circle(point,float8) </ENTRY> |
||||
<ENTRY> circle </ENTRY> |
||||
<ENTRY> convert to circle </ENTRY> |
||||
<ENTRY> circle('(0,0)'::point,2.0) </ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> lseg(box) </ENTRY> |
||||
<ENTRY> lseg </ENTRY> |
||||
<ENTRY> convert diagonal to lseg </ENTRY> |
||||
<ENTRY> lseg('((-1,0),(1,0))'::box) </ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> lseg(point,point) </ENTRY> |
||||
<ENTRY> lseg </ENTRY> |
||||
<ENTRY> convert to lseg </ENTRY> |
||||
<ENTRY> lseg('(-1,0)'::point,'(1,0)'::point) </ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> path(polygon) </ENTRY> |
||||
<ENTRY> point </ENTRY> |
||||
<ENTRY> convert to path </ENTRY> |
||||
<ENTRY> path('((0,0),(1,1),(2,0))'::polygon) </ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> point(circle) </ENTRY> |
||||
<ENTRY> point </ENTRY> |
||||
<ENTRY> convert to point (center) </ENTRY> |
||||
<ENTRY> point('((0,0),2.0)'::circle) </ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> point(lseg,lseg) </ENTRY> |
||||
<ENTRY> point </ENTRY> |
||||
<ENTRY> convert to point (intersection) </ENTRY> |
||||
<ENTRY> point('((-1,0),(1,0))'::lseg,'((-2,-2),(2,2))'::lseg) </ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> point(polygon) </ENTRY> |
||||
<ENTRY> point </ENTRY> |
||||
<ENTRY> center of polygon </ENTRY> |
||||
<ENTRY> point('((0,0),(1,1),(2,0))'::polygon) </ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> polygon(box) </ENTRY> |
||||
<ENTRY> polygon </ENTRY> |
||||
<ENTRY> convert to polygon with 12 points </ENTRY> |
||||
<ENTRY> polygon('((0,0),(1,1))'::box) </ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> polygon(circle) </ENTRY> |
||||
<ENTRY> polygon </ENTRY> |
||||
<ENTRY> convert to polygon with 12 points </ENTRY> |
||||
<ENTRY> polygon('((0,0),2.0)'::circle) </ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> polygon(npts,circle) </ENTRY> |
||||
<ENTRY> polygon </ENTRY> |
||||
<ENTRY> convert to polygon with npts points </ENTRY> |
||||
<ENTRY> polygon(12,'((0,0),2.0)'::circle) </ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> polygon(path) </ENTRY> |
||||
<ENTRY> polygon </ENTRY> |
||||
<ENTRY> convert to polygon </ENTRY> |
||||
<ENTRY> polygon('((0,0),(1,1),(2,0))'::path) </ENTRY> |
||||
</ROW> |
||||
</TBODY> |
||||
</TGROUP> |
||||
</TABLE> |
||||
</Para> |
||||
|
||||
<Para> |
||||
<TABLE TOCENTRY="1"> |
||||
<TITLE>Geometric Upgrade Functions</TITLE> |
||||
<TGROUP COLS="4"> |
||||
<THEAD> |
||||
<ROW> |
||||
<ENTRY>Function</ENTRY> |
||||
<ENTRY>Returns</ENTRY> |
||||
<ENTRY>Description</ENTRY> |
||||
<ENTRY>Example</ENTRY> |
||||
</ROW> |
||||
</THEAD> |
||||
<TBODY> |
||||
<ROW> |
||||
<ENTRY> isoldpath(path) </ENTRY> |
||||
<ENTRY> path </ENTRY> |
||||
<ENTRY> test path for pre-v6.1 form </ENTRY> |
||||
<ENTRY> isoldpath('(1,3,0,0,1,1,2,0)'::path) </ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> revertpoly(polygon) </ENTRY> |
||||
<ENTRY> polygon </ENTRY> |
||||
<ENTRY> convert pre-v6.1 polygon </ENTRY> |
||||
<ENTRY> revertpoly('((0,0),(1,1),(2,0))'::polygon) </ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> upgradepath(path) </ENTRY> |
||||
<ENTRY> path </ENTRY> |
||||
<ENTRY> convert pre-v6.1 path </ENTRY> |
||||
<ENTRY> upgradepath('(1,3,0,0,1,1,2,0)'::path) </ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> upgradepoly(polygon) </ENTRY> |
||||
<ENTRY> polygon </ENTRY> |
||||
<ENTRY> convert pre-v6.1 polygon </ENTRY> |
||||
<ENTRY> upgradepoly('(0,1,2,0,1,0)'::polygon) </ENTRY> |
||||
</ROW> |
||||
</TBODY> |
||||
</TGROUP> |
||||
</TABLE> |
||||
</Para> |
||||
|
||||
</chapter> |
||||
|
||||
@ -0,0 +1,458 @@ |
||||
<Chapter> |
||||
<Title>Operators</Title> |
||||
|
||||
<Abstract> |
||||
<Para> |
||||
Describes the built-in operators available in <ProductName>Postgres</ProductName>. |
||||
</Para> |
||||
</Abstract> |
||||
|
||||
<Para> |
||||
<ProductName>Postgres</ProductName> provides a large number of built-in operators on system types. |
||||
These operators are declared in the system catalog |
||||
pg_operator. Every entry in pg_operator includes |
||||
the name of the procedure that implements the operator and the |
||||
class <Acronym>OIDs</Acronym> of the input and output types. |
||||
|
||||
<Para> |
||||
To view all variations of the <Quote>||</Quote> string concatenation operator, try |
||||
<ProgramListing> |
||||
SELECT oprleft, oprright, oprresult, oprcode |
||||
FROM pg_operator WHERE oprname = '||'; |
||||
|
||||
oprleft|oprright|oprresult|oprcode |
||||
-------+--------+---------+------- |
||||
25| 25| 25|textcat |
||||
1042| 1042| 1042|textcat |
||||
1043| 1043| 1043|textcat |
||||
(3 rows) |
||||
</ProgramListing> |
||||
</Para> |
||||
|
||||
<sect1> |
||||
<title>General Operators</title> |
||||
|
||||
<para> |
||||
The operators listed here are defined for a number of native data types, ranging |
||||
from numeric types to data/time types. |
||||
|
||||
<Para> |
||||
<TABLE TOCENTRY="1"> |
||||
<TITLE><ProductName>Postgres</ProductName> Operators</TITLE> |
||||
<TITLEABBREV>Operators</TITLEABBREV> |
||||
<TGROUP COLS="3"> |
||||
<THEAD> |
||||
<ROW> |
||||
<ENTRY>Operator</ENTRY> |
||||
<ENTRY>Description</ENTRY> |
||||
<ENTRY>Usage</ENTRY> |
||||
</ROW> |
||||
</THEAD> |
||||
<TBODY> |
||||
<ROW> |
||||
<ENTRY> < </ENTRY> |
||||
<ENTRY>Less than?</ENTRY> |
||||
<ENTRY>1 < 2</ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> <= </ENTRY> |
||||
<ENTRY>Less than or equal to?</ENTRY> |
||||
<ENTRY>1 <= 2</ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> <> </ENTRY> |
||||
<ENTRY>Not equal?</ENTRY> |
||||
<ENTRY>1 <> 2</ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> = </ENTRY> |
||||
<ENTRY>Equal?</ENTRY> |
||||
<ENTRY>1 = 1</ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> > </ENTRY> |
||||
<ENTRY>Greater than?</ENTRY> |
||||
<ENTRY>2 > 1</ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> >= </ENTRY> |
||||
<ENTRY>Greater than or equal to?</ENTRY> |
||||
<ENTRY>2 >= 1</ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> || </ENTRY> |
||||
<ENTRY>Concatenate strings</ENTRY> |
||||
<ENTRY>'Postgre' || 'SQL'</ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> !!= </ENTRY> |
||||
<ENTRY>NOT IN</ENTRY> |
||||
<ENTRY>3 !!= i</ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> ~~ </ENTRY> |
||||
<ENTRY>LIKE</ENTRY> |
||||
<ENTRY>'scrappy,marc,hermit' ~~ '%scrappy%'</ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> !~~ </ENTRY> |
||||
<ENTRY>NOT LIKE</ENTRY> |
||||
<ENTRY>'bruce' !~~ '%al%'</ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> ~ </ENTRY> |
||||
<ENTRY>Match (regex), case sensitive</ENTRY> |
||||
<ENTRY>'thomas' ~ '*.thomas*.'</ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> ~* </ENTRY> |
||||
<ENTRY>Match (regex), case insensitive</ENTRY> |
||||
<ENTRY>'thomas' ~* '*.Thomas*.'</ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> !~ </ENTRY> |
||||
<ENTRY>Does not match (regex), case sensitive</ENTRY> |
||||
<ENTRY>'thomas' !~ '*.Thomas*.'</ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> !~* </ENTRY> |
||||
<ENTRY>Does not match (regex), case insensitive</ENTRY> |
||||
<ENTRY>'thomas' !~ '*.vadim*.'</ENTRY> |
||||
</ROW> |
||||
</TBODY> |
||||
</TGROUP> |
||||
</TABLE> |
||||
</Para> |
||||
|
||||
<sect1> |
||||
<title>Numerical Operators</title> |
||||
|
||||
<Para> |
||||
<TABLE TOCENTRY="1"> |
||||
<TITLE><ProductName>Postgres</ProductName> Numerical Operators</TITLE> |
||||
<TITLEABBREV>Operators</TITLEABBREV> |
||||
<TGROUP COLS="3"> |
||||
<THEAD> |
||||
<ROW> |
||||
<ENTRY>Operator</ENTRY> |
||||
<ENTRY>Description</ENTRY> |
||||
<ENTRY>Usage</ENTRY> |
||||
</ROW> |
||||
</THEAD> |
||||
<TBODY> |
||||
<ROW> |
||||
<ENTRY> ! </ENTRY> |
||||
<ENTRY>Factorial</ENTRY> |
||||
<ENTRY>3 !</ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> !! </ENTRY> |
||||
<ENTRY>Factorial (left operator)</ENTRY> |
||||
<ENTRY>!! 3</ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> % </ENTRY> |
||||
<ENTRY>Modulo</ENTRY> |
||||
<ENTRY>5 % 4</ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> % </ENTRY> |
||||
<ENTRY>Truncate</ENTRY> |
||||
<ENTRY>% 4.5</ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> * </ENTRY> |
||||
<ENTRY>Multiplication</ENTRY> |
||||
<ENTRY>2 * 3</ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> + </ENTRY> |
||||
<ENTRY>Addition</ENTRY> |
||||
<ENTRY>2 + 3</ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> - </ENTRY> |
||||
<ENTRY>Subtraction</ENTRY> |
||||
<ENTRY>2 - 3</ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> / </ENTRY> |
||||
<ENTRY>Division</ENTRY> |
||||
<ENTRY>4 / 2</ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> : </ENTRY> |
||||
<ENTRY>Natural Exponentiation</ENTRY> |
||||
<ENTRY>: 3.0</ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> ; </ENTRY> |
||||
<ENTRY>Natural Logarithm</ENTRY> |
||||
<ENTRY>(; 5.0)</ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> @ </ENTRY> |
||||
<ENTRY>Absolute value</ENTRY> |
||||
<ENTRY>@ -5.0</ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> ^ </ENTRY> |
||||
<ENTRY>Exponentiation</ENTRY> |
||||
<ENTRY>2.0 ^ 3.0</ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> |/ </ENTRY> |
||||
<ENTRY>Square root</ENTRY> |
||||
<ENTRY>|/ 25.0</ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> ||/ </ENTRY> |
||||
<ENTRY>Cube root</ENTRY> |
||||
<ENTRY>||/ 27.0</ENTRY> |
||||
</ROW> |
||||
</TBODY> |
||||
</TGROUP> |
||||
</TABLE> |
||||
</Para> |
||||
|
||||
<sect1> |
||||
<title>Geometric Operators</title> |
||||
|
||||
<Para> |
||||
<TABLE TOCENTRY="1"> |
||||
<TITLE><ProductName>Postgres</ProductName> Geometric Operators</TITLE> |
||||
<TITLEABBREV>Operators</TITLEABBREV> |
||||
<TGROUP COLS="3"> |
||||
<THEAD> |
||||
<ROW> |
||||
<ENTRY>Operator</ENTRY> |
||||
<ENTRY>Description</ENTRY> |
||||
<ENTRY>Usage</ENTRY> |
||||
</ROW> |
||||
</THEAD> |
||||
<TBODY> |
||||
<ROW> |
||||
<ENTRY> + </ENTRY> |
||||
<ENTRY>Translation</ENTRY> |
||||
<ENTRY>'((0,0),(1,1))'::box + '(2.0,0)'::point</ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> - </ENTRY> |
||||
<ENTRY>Translation</ENTRY> |
||||
<ENTRY>'((0,0),(1,1))'::box - '(2.0,0)'::point</ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> * </ENTRY> |
||||
<ENTRY>Scaling/rotation</ENTRY> |
||||
<ENTRY>'((0,0),(1,1))'::box * '(2.0,0)'::point</ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> / </ENTRY> |
||||
<ENTRY>Scaling/rotation</ENTRY> |
||||
<ENTRY>'((0,0),(2,2))'::box / '(2.0,0)'::point</ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> # </ENTRY> |
||||
<ENTRY>Intersection</ENTRY> |
||||
<ENTRY>'((1,-1),(-1,1))' # '((1,1),(-1,-1))'</ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> # </ENTRY> |
||||
<ENTRY>Number of points in polygon</ENTRY> |
||||
<ENTRY># '((1,0),(0,1),(-1,0))'</ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> ## </ENTRY> |
||||
<ENTRY>Point of closest proximity</ENTRY> |
||||
<ENTRY>'(0,0)'::point ## '((2,0),(0,2))'::lseg</ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> && </ENTRY> |
||||
<ENTRY>Overlaps?</ENTRY> |
||||
<ENTRY>'((0,0),(1,1))'::box && '((0,0),(2,2))'::box</ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> &< </ENTRY> |
||||
<ENTRY>Overlaps to left?</ENTRY> |
||||
<ENTRY>'((0,0),(1,1))'::box &< '((0,0),(2,2))'::box</ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> &> </ENTRY> |
||||
<ENTRY>Overlaps to right?</ENTRY> |
||||
<ENTRY>'((0,0),(3,3))'::box &> '((0,0),(2,2))'::box</ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> <-> </ENTRY> |
||||
<ENTRY>Distance between</ENTRY> |
||||
<ENTRY>'((0,0),1)'::circle <-> '((5,0),1)'::circle</ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> << </ENTRY> |
||||
<ENTRY>Left of?</ENTRY> |
||||
<ENTRY>'((0,0),1)'::circle << '((5,0),1)'::circle</ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> <^ </ENTRY> |
||||
<ENTRY>Is below?</ENTRY> |
||||
<ENTRY>'((0,0),1)'::circle <^ '((0,5),1)'::circle</ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> >> </ENTRY> |
||||
<ENTRY>Is right of?</ENTRY> |
||||
<ENTRY>'((5,0),1)'::circle >> '((0,0),1)'::circle</ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> >^ </ENTRY> |
||||
<ENTRY>Is above?</ENTRY> |
||||
<ENTRY>'((0,5),1)'::circle >^ '((0,0),1)'::circle</ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> ?# </ENTRY> |
||||
<ENTRY>Intersects or overlaps</ENTRY> |
||||
<ENTRY>'((-1,0),(1,0))'::lseg ?# '((-2,-2),(2,2))'::box;</ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> ?- </ENTRY> |
||||
<ENTRY>Is horizontal?</ENTRY> |
||||
<ENTRY>'(1,0)'::point ?- '(0,0)'::point</ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> ?-| </ENTRY> |
||||
<ENTRY>Is perpendicular?</ENTRY> |
||||
<ENTRY>'((0,0),(0,1))'::lseg ?-| '((0,0),(1,0))'::lseg</ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> @-@ </ENTRY> |
||||
<ENTRY>Length or circumference</ENTRY> |
||||
<ENTRY>@-@ '((0,0),(1,0))'::path</ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> ?| </ENTRY> |
||||
<ENTRY>Is vertical?</ENTRY> |
||||
<ENTRY>'(0,1)'::point ?| '(0,0)'::point</ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> ?|| </ENTRY> |
||||
<ENTRY>Is parallel?</ENTRY> |
||||
<ENTRY>'((-1,0),(1,0))'::lseg ?|| '((-1,2),(1,2))'::lseg</ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> @ </ENTRY> |
||||
<ENTRY>Contained or on</ENTRY> |
||||
<ENTRY>'(1,1)'::point @ '((0,0),2)'::circle</ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> @@ </ENTRY> |
||||
<ENTRY>Center of</ENTRY> |
||||
<ENTRY>@@ '((0,0),10)'::circle</ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> ~= </ENTRY> |
||||
<ENTRY>Same as</ENTRY> |
||||
<ENTRY>'((0,0),(1,1))'::polygon ~= '((1,1),(0,0))'::polygon</ENTRY> |
||||
</ROW> |
||||
</TBODY> |
||||
</TGROUP> |
||||
</TABLE> |
||||
</Para> |
||||
|
||||
<sect1> |
||||
<title>Time Interval Operators</title> |
||||
|
||||
<Para> |
||||
The time interval data type <Type>tinterval</Type> is a legacy from the original |
||||
date/time types and is not as well supported as the more modern types. There |
||||
are several operators for this type. |
||||
|
||||
<TABLE TOCENTRY="1"> |
||||
<TITLE><ProductName>Postgres</ProductName> Time Interval Operators</TITLE> |
||||
<TITLEABBREV>Operators</TITLEABBREV> |
||||
<TGROUP COLS="3"> |
||||
<THEAD> |
||||
<ROW> |
||||
<ENTRY>Operator</ENTRY> |
||||
<ENTRY>Description</ENTRY> |
||||
<ENTRY>Usage</ENTRY> |
||||
</ROW> |
||||
</THEAD> |
||||
<TBODY> |
||||
<ROW> |
||||
<ENTRY> #< </ENTRY> |
||||
<ENTRY>Interval less than?</ENTRY> |
||||
<ENTRY></ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> #<= </ENTRY> |
||||
<ENTRY>Interval less than or equal to?</ENTRY> |
||||
<ENTRY></ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> #<> </ENTRY> |
||||
<ENTRY>Interval not equal?</ENTRY> |
||||
<ENTRY></ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> #= </ENTRY> |
||||
<ENTRY>Interval equal?</ENTRY> |
||||
<ENTRY></ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> #> </ENTRY> |
||||
<ENTRY>Interval greater than?</ENTRY> |
||||
<ENTRY></ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> #>= </ENTRY> |
||||
<ENTRY>Interval greater than or equal to?</ENTRY> |
||||
<ENTRY></ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> <#> </ENTRY> |
||||
<ENTRY>Convert to time interval</ENTRY> |
||||
<ENTRY></ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> << </ENTRY> |
||||
<ENTRY>Interval less than?</ENTRY> |
||||
<ENTRY></ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> | </ENTRY> |
||||
<ENTRY>Start of interval</ENTRY> |
||||
<ENTRY></ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> ~= </ENTRY> |
||||
<ENTRY>Same as</ENTRY> |
||||
<ENTRY></ENTRY> |
||||
</ROW> |
||||
<ROW> |
||||
<ENTRY> <?> </ENTRY> |
||||
<ENTRY>Time inside interval?</ENTRY> |
||||
<ENTRY></ENTRY> |
||||
</ROW> |
||||
</TBODY> |
||||
</TGROUP> |
||||
</TABLE> |
||||
</Para> |
||||
|
||||
|
||||
<Para> |
||||
Users may invoke operators using the operator name, as in: |
||||
|
||||
<ProgramListing> |
||||
select * from emp where salary < 40000; |
||||
</ProgramListing> |
||||
|
||||
Alternatively, users may call the functions that implement the |
||||
operators directly. In this case, the query above would be expressed |
||||
as: |
||||
<ProgramListing> |
||||
select * from emp where int4lt(salary, 40000); |
||||
</ProgramListing> |
||||
|
||||
<Para> |
||||
<Application>psql</Application> |
||||
has a command (<Command>\dd</Command>) to show these operators. |
||||
</Chapter> |
||||
|
||||
File diff suppressed because it is too large
Load Diff
@ -0,0 +1,653 @@ |
||||
<chapter> |
||||
<title>Type Conversion</title> |
||||
|
||||
<para> |
||||
<acronym>SQL</acronym> queries can, intentionally or not, require |
||||
mixing of different data types in the same expression. |
||||
<productname>Postgres</productname> has extensive facilities for |
||||
evaluating mixed-type expressions. |
||||
|
||||
<para> |
||||
In many cases a user will not need |
||||
to understand the details of the type conversion mechanism. |
||||
However, the implicit conversions done by <productname>Postgres</productname> |
||||
can affect the apparent results of a query, and these results |
||||
can be tailored by a user or programmer |
||||
using <emphasis>explicit</emphasis> type coersion. |
||||
|
||||
<para> |
||||
This chapter introduces the <productname>Postgres</productname> |
||||
type conversion mechanisms and conventions. |
||||
Refer to the relevant sections in the User's Guide and Programmer's Guide |
||||
for more information on specific data types and allowed functions and operators. |
||||
|
||||
<para> |
||||
The Programmer's Guide has more details on the exact algorithms used for |
||||
implicit type conversion and coersion. |
||||
|
||||
<sect1> |
||||
<title>Overview</title> |
||||
|
||||
<para> |
||||
<acronym>SQL</acronym> is a strongly typed language. That is, every data item |
||||
has an associated data type which determines its behavior and allowed usage. |
||||
<productname>Postgres</productname> has an extensible type system which is |
||||
much more general and flexible than other <acronym>RDBMS</acronym> implementations. |
||||
Hence, most type conversion behavior in <productname>Postgres</productname> |
||||
should be governed by general rules rather than by ad-hoc heuristics to allow |
||||
mixed-type expressions to be meaningful, even with user-defined types. |
||||
|
||||
<para> |
||||
The <productname>Postgres</productname> scanner/parser decodes lexical elements |
||||
into only five fundamental categories: integers, floats, strings, names, and keywords. |
||||
Most extended types are first tokenized into strings. The <acronym>SQL</acronym> |
||||
language definition allows specifying type names with strings, and this mechanism |
||||
is used by <productname>Postgres</productname> |
||||
to start the parser down the correct path. For example, the query |
||||
|
||||
<programlisting> |
||||
tgl=> SELECT text 'Origin' AS "Label", point '(0,0)' AS "Value"; |
||||
Label |Value |
||||
------+----- |
||||
Origin|(0,0) |
||||
(1 row) |
||||
</programlisting> |
||||
|
||||
has two strings, of type <type>text</type> and <type>point</type>. |
||||
If a type is not specified, then the placeholder type <type>unknown</type> |
||||
is assigned initially, to be resolved in later stages as described below. |
||||
|
||||
<para> |
||||
There are four fundamental <acronym>SQL</acronym> constructs requiring |
||||
distinct type conversion rules in the <productname>Postgres</productname> |
||||
parser: |
||||
|
||||
<variablelist> |
||||
<varlistentry> |
||||
<term> |
||||
Operators |
||||
</term> |
||||
<listitem> |
||||
<para> |
||||
<productname>Postgres</productname> allows expressions with |
||||
left- and right-unary (one argument) operators, |
||||
as well as binary (two argument) operators. |
||||
</listitem> |
||||
</varlistentry> |
||||
<varlistentry> |
||||
<term> |
||||
Function calls |
||||
</term> |
||||
<listitem> |
||||
<para> |
||||
Much of the <productname>Postgres</productname> type system is built around a rich set of |
||||
functions. Function calls have one or more arguments which, for any specific query, |
||||
must be matched to the functions available in the system catalog. |
||||
</listitem> |
||||
</varlistentry> |
||||
<varlistentry> |
||||
<term> |
||||
Query targets |
||||
</term> |
||||
<listitem> |
||||
<para> |
||||
<acronym>SQL</acronym> INSERT statements place the results of query into a table. The expressions |
||||
in the query must be matched up with, and perhaps converted to, the target columns of the insert. |
||||
</listitem> |
||||
</varlistentry> |
||||
<varlistentry> |
||||
<term> |
||||
UNION queries |
||||
</term> |
||||
<listitem> |
||||
<para> |
||||
Since all select results from a UNION SELECT statement must appear in a single set of columns, the types |
||||
of each SELECT clause must be matched up and converted to a uniform set. |
||||
</listitem> |
||||
</varlistentry> |
||||
</variablelist> |
||||
|
||||
<para> |
||||
Many of the general type conversion rules use simple conventions built on |
||||
the <productname>Postgres</productname> function and operator system tables. |
||||
There are some heuristics included in the conversion rules to better support |
||||
conventions for the <acronym>SQL92</acronym> standard native types such as |
||||
<type>smallint</type>, <type>integer</type>, and <type>float</type>. |
||||
|
||||
<para> |
||||
The <productname>Postgres</productname> parser uses the convention that all |
||||
type conversion functions take a single argument of the source type and are |
||||
named with the same name as the target type. Any function meeting this |
||||
criteria is considered to be a valid conversion function, and may be used |
||||
by the parser as such. This simple assumption gives the parser the power |
||||
to explore type conversion possibilities without hardcoding, allowing |
||||
extended user-defined types to use these same features transparently. |
||||
|
||||
<para> |
||||
An additional heuristic is provided in the parser to allow better guesses |
||||
at proper behavior for <acronym>SQL</acronym> standard types. There are |
||||
five categories of types defined: boolean, string, numeric, geometric, |
||||
and user-defined. Each category, with the exception of user-defined, has |
||||
a "preferred type" which is used to resolve ambiguities in candidates. |
||||
Each "user-defined" type is its own "preferred type", so ambiguous |
||||
expressions (those with multiple candidate parsing solutions) |
||||
with only one user-defined type can resolve to a single best choice, while those with |
||||
multiple user-defined types will remain ambiguous and throw an error. |
||||
|
||||
<para> |
||||
Ambiguous expressions which have candidate solutions within only one type category are |
||||
likely to resolve, while ambiguous expressions with candidates spanning multiple |
||||
categories are likely to throw an error and ask for clarification from the user. |
||||
|
||||
<sect2> |
||||
<title>Guidelines</title> |
||||
|
||||
<para> |
||||
All type conversion rules are designed with several principles in mind: |
||||
|
||||
<itemizedlist mark="bullet" spacing="compact"> |
||||
<listitem> |
||||
<para> |
||||
Implicit conversions should never have suprising or unpredictable outcomes. |
||||
|
||||
<listitem> |
||||
<para> |
||||
User-defined types, of which the parser has no apriori knowledge, should be |
||||
"higher" in the type heirarchy. In mixed-type expressions, native types shall always |
||||
be converted to a user-defined type (of course, only if conversion is necessary). |
||||
|
||||
<listitem> |
||||
<para> |
||||
User-defined types are not related. Currently, <productname>Postgres</productname> |
||||
does not have information available to it on relationships between types, other than |
||||
hardcoded heuristics for built-in types and implicit relationships based on available functions |
||||
in the catalog. |
||||
|
||||
<listitem> |
||||
<para> |
||||
There should be no extra overhead from the parser or executor |
||||
if a query does not need implicit type conversion. |
||||
That is, if a query is well formulated and the types already match up, then the query should proceed |
||||
without spending extra time in the parser and without introducing unnecessary implicit conversion |
||||
functions into the query. |
||||
|
||||
<para> |
||||
Additionally, if a query usually requires an implicit conversion for a function, and |
||||
if then the user defines an explicit function with the correct argument types, the parser |
||||
should use this new function and will no longer do the implicit conversion using the old function. |
||||
</itemizedlist> |
||||
|
||||
<sect1> |
||||
<title>Operators</title> |
||||
|
||||
<sect2> |
||||
<title>Conversion Procedure</title> |
||||
|
||||
<para> |
||||
<procedure> |
||||
<title>Operator Evaluation</title> |
||||
|
||||
<para> |
||||
|
||||
<step performance="required"> |
||||
<para> |
||||
Check for an exact match in the pg_operator system catalog. |
||||
|
||||
<substeps> |
||||
<step performance="optional"> |
||||
<para> |
||||
If one argument of a binary operator is <type>unknown</type>, |
||||
then assume it is the same type as the other argument. |
||||
|
||||
<step performance="required"> |
||||
<para> |
||||
Reverse the arguments, and look for an exact match with an operator which |
||||
points to itself as being commutative. |
||||
If found, then reverse the arguments in the parse tree and use this operator. |
||||
|
||||
</substeps> |
||||
|
||||
<step performance="required"> |
||||
<para> |
||||
Look for the best match. |
||||
|
||||
<substeps> |
||||
<step performance="optional"> |
||||
<para> |
||||
Make a list of all operators of the same name. |
||||
|
||||
<step performance="required"> |
||||
<para> |
||||
If only one operator is in the list, use it if the input type can be coerced, |
||||
and throw an error if the type cannot be coerced. |
||||
|
||||
<step performance="required"> |
||||
<para> |
||||
Keep all operators with the most explicit matches for types. Keep all if there |
||||
are no explicit matches and move to the next step. |
||||
If only one candidate remains, use it if the type can be coerced. |
||||
|
||||
<step performance="required"> |
||||
<para> |
||||
If any input arguments are "unknown", categorize the input candidates as |
||||
boolean, numeric, string, geometric, or user-defined. If there is a mix of |
||||
categories, or more than one user-defined type, throw an error because |
||||
the correct choice cannot be deduced without more clues. |
||||
If only one category is present, then assign the "preferred type" |
||||
to the input column which had been previously "unknown". |
||||
|
||||
<step performance="required"> |
||||
<para> |
||||
Choose the candidate with the most exact type matches, and which matches |
||||
the "preferred type" for each column category from the previous step. |
||||
If there is still more than one candidate, or if there are none, |
||||
then throw an error. |
||||
</substeps> |
||||
|
||||
</procedure> |
||||
|
||||
<sect2> |
||||
<title>Examples</title> |
||||
|
||||
<sect3> |
||||
<title>Exponentiation Operator</title> |
||||
|
||||
<para> |
||||
There is only one exponentiation |
||||
operator defined in the catalog, and it takes <type>float8</type> arguments. |
||||
The scanner assigns an initial type of <type>int4</type> to both arguments |
||||
of this query expression: |
||||
<programlisting> |
||||
tgl=> select 2 ^ 3 AS "Exp"; |
||||
Exp |
||||
--- |
||||
8 |
||||
(1 row) |
||||
</programlisting> |
||||
|
||||
So the parser does a type conversion on both operands and the query |
||||
is equivalent to |
||||
|
||||
<programlisting> |
||||
tgl=> select float8(2) ^ float8(3) AS "Exp"; |
||||
Exp |
||||
--- |
||||
8 |
||||
(1 row) |
||||
</programlisting> |
||||
|
||||
or |
||||
|
||||
<programlisting> |
||||
tgl=> select 2.0 ^ 3.0 AS "Exp"; |
||||
Exp |
||||
--- |
||||
8 |
||||
(1 row) |
||||
</programlisting> |
||||
|
||||
<note> |
||||
<para> |
||||
This last form has the least overhead, since no functions are called to do |
||||
implicit type conversion. This is not an issue for small queries, but may |
||||
have an impact on the performance of queries involving large tables. |
||||
</note> |
||||
|
||||
<sect3> |
||||
<title>String Concatenation</title> |
||||
|
||||
<para> |
||||
A string-like syntax is used for working with string types as well as for |
||||
working with complex extended types. |
||||
Strings with unspecified type are matched with likely operator candidates. |
||||
|
||||
<para> |
||||
One unspecified argument: |
||||
<programlisting> |
||||
tgl=> SELECT text 'abc' || 'def' AS "Text and Unknown"; |
||||
Text and Unknown |
||||
---------------- |
||||
abcdef |
||||
(1 row) |
||||
</programlisting> |
||||
|
||||
<para> |
||||
In this case the parser looks to see if there is an operator taking <type>text</type> |
||||
for both arguments. Since there is, it assumes that the second argument should |
||||
be interpreted as of type <type>text</type>. |
||||
|
||||
<para> |
||||
Concatenation on unspecified types: |
||||
<programlisting> |
||||
tgl=> SELECT 'abc' || 'def' AS "Unspecified"; |
||||
Unspecified |
||||
----------- |
||||
abcdef |
||||
(1 row) |
||||
</programlisting> |
||||
|
||||
<para> |
||||
In this case there is no initial hint for which type to use, since no types |
||||
are specified in the query. So, the parser looks for all candidate operators |
||||
and finds that all arguments for all the candidates are string types. It chooses |
||||
the "preferred type" for strings, <type>text</type>, for this query. |
||||
|
||||
<note> |
||||
<para> |
||||
If a user defines a new type and defines an operator <quote>||</quote> to work |
||||
with it, then this query would no longer succeed as written. The parser would |
||||
now have candidate types from two categories, and could not decide which to use. |
||||
</note> |
||||
|
||||
<sect3> |
||||
<title>Factorial</title> |
||||
|
||||
<para> |
||||
This example illustrates an interesting result. Traditionally, the |
||||
factorial operator is defined for integers only. The <productname>Postgres</productname> |
||||
operator catalog has only one entry for factorial, taking an integer operand. |
||||
If given a non-integer numeric argument, <productname>Postgres</productname> |
||||
will try to convert that argument to an integer for evaluation of the |
||||
factorial. |
||||
|
||||
<programlisting> |
||||
tgl=> select (4.3 !); |
||||
?column? |
||||
-------- |
||||
24 |
||||
(1 row) |
||||
</programlisting> |
||||
|
||||
<note> |
||||
<para> |
||||
Of course, this leads to a mathematically suspect result, |
||||
since in principle the factorial of a non-integer is not defined. |
||||
However, the role of a database is not to teach mathematics, but |
||||
to be a tool for data manipulation. If a user chooses to take the |
||||
factorial of a floating point number, <productname>Postgres</productname> |
||||
will try to oblige. |
||||
</note> |
||||
|
||||
<sect1> |
||||
<title>Functions</title> |
||||
|
||||
<para> |
||||
|
||||
<procedure> |
||||
<title>Function Evaluation</title> |
||||
|
||||
<step performance="required"> |
||||
<para> |
||||
Check for an exact match in the pg_proc system catalog. |
||||
|
||||
<step performance="required"> |
||||
<para> |
||||
Look for the best match. |
||||
|
||||
<substeps> |
||||
<step performance="required"> |
||||
<para> |
||||
Make a list of all functions of the same name with the same number of arguments. |
||||
|
||||
<step performance="required"> |
||||
<para> |
||||
If only one function is in the list, use it if the input types can be coerced, |
||||
and throw an error if the types cannot be coerced. |
||||
|
||||
<step performance="required"> |
||||
<para> |
||||
Keep all functions with the most explicit matches for types. Keep all if there |
||||
are no explicit matches and move to the next step. |
||||
If only one candidate remains, use it if the type can be coerced. |
||||
|
||||
<step performance="required"> |
||||
<para> |
||||
If any input arguments are "unknown", categorize the input candidate arguments as |
||||
boolean, numeric, string, geometric, or user-defined. If there is a mix of |
||||
categories, or more than one user-defined type, throw an error because |
||||
the correct choice cannot be deduced without more clues. |
||||
If only one category is present, then assign the "preferred type" |
||||
to the input column which had been previously "unknown". |
||||
|
||||
<step performance="required"> |
||||
<para> |
||||
Choose the candidate with the most exact type matches, and which matches |
||||
the "preferred type" for each column category from the previous step. |
||||
If there is still more than one candidate, or if there are none, |
||||
then throw an error. |
||||
</substeps> |
||||
|
||||
</procedure> |
||||
|
||||
<sect2> |
||||
<title>Examples</title> |
||||
|
||||
<sect3> |
||||
<title>Factorial Function</title> |
||||
|
||||
<para> |
||||
There is only one factorial function defined in the pg_proc catalog. |
||||
So the following query automatically converts the <type>int2</type> argument |
||||
to <type>int4</type>: |
||||
|
||||
<programlisting> |
||||
tgl=> select int4fac(int2 '4'); |
||||
int4fac |
||||
------- |
||||
24 |
||||
(1 row) |
||||
</programlisting> |
||||
|
||||
and is actually transformed by the parser to |
||||
<programlisting> |
||||
tgl=> select int4fac(int4(int2 '4')); |
||||
int4fac |
||||
------- |
||||
24 |
||||
(1 row) |
||||
</programlisting> |
||||
|
||||
<sect3> |
||||
<title>Substring Function</title> |
||||
|
||||
<para> |
||||
There are two <function>substr</function> functions declared in pg_proc. However, |
||||
only one takes two arguments, of types <type>text</type> and <type>int4</type>. |
||||
|
||||
<para> |
||||
If called with a string constant of unspecified type, the type is matched up |
||||
directly with the only candidate function type: |
||||
<programlisting> |
||||
tgl=> select substr('1234', 3); |
||||
substr |
||||
------ |
||||
34 |
||||
(1 row) |
||||
</programlisting> |
||||
|
||||
<para> |
||||
If the string is declared to be of type <type>varchar</type>, as might be the case |
||||
if it comes from a table, then the parser will try to coerce it to become <type>text</type>: |
||||
<programlisting> |
||||
tgl=> select substr(varchar '1234', 3); |
||||
substr |
||||
------ |
||||
34 |
||||
(1 row) |
||||
</programlisting> |
||||
which is transformed by the parser to become |
||||
<programlisting> |
||||
tgl=> select substr(text(varchar '1234'), 3); |
||||
substr |
||||
------ |
||||
34 |
||||
(1 row) |
||||
</programlisting> |
||||
<note> |
||||
<para> |
||||
There are some heuristics in the parser to optimize the relationship between the |
||||
<type>char</type>, <type>varchar</type>, and <type>text</type> types. |
||||
For this case, <function>substr</function> is called directly with the <type>varchar</type> string |
||||
rather than inserting an explicit conversion call. |
||||
</note> |
||||
|
||||
<para> |
||||
And, if the function is called with an <type>int4</type>, the parser will |
||||
try to convert that to <type>text</type>: |
||||
<programlisting> |
||||
tgl=> select substr(1234, 3); |
||||
substr |
||||
------ |
||||
34 |
||||
(1 row) |
||||
</programlisting> |
||||
actually executes as |
||||
<programlisting> |
||||
tgl=> select substr(text(1234), 3); |
||||
substr |
||||
------ |
||||
34 |
||||
(1 row) |
||||
</programlisting> |
||||
|
||||
<sect1> |
||||
<title>Query Targets</title> |
||||
|
||||
<para> |
||||
|
||||
<procedure> |
||||
<title>Target Evaluation</title> |
||||
|
||||
<step performance="required"> |
||||
<para> |
||||
Check for an exact match with the target. |
||||
|
||||
<step performance="required"> |
||||
<para> |
||||
Try to coerce the expression directly to the target type if necessary. |
||||
|
||||
<step performance="required"> |
||||
<para> |
||||
If the target is a fixed-length type (e.g. <type>char</type> or <type>varchar</type> |
||||
declared with a length) then try to find a sizing function of the same name |
||||
as the type taking two arguments, the first the type name and the second an |
||||
integer length. |
||||
|
||||
</procedure> |
||||
|
||||
<sect2> |
||||
<title>Examples</title> |
||||
|
||||
<sect3> |
||||
<title><type>varchar</type> Storage</title> |
||||
|
||||
<para> |
||||
For a target column declared as <type>varchar(4)</type> the following query |
||||
ensures that the target is sized correctly: |
||||
|
||||
<programlisting> |
||||
tgl=> CREATE TABLE vv (v varchar(4)); |
||||
CREATE |
||||
tgl=> INSERT INTO vv SELECT 'abc' || 'def'; |
||||
INSERT 392905 1 |
||||
tgl=> select * from vv; |
||||
v |
||||
---- |
||||
abcd |
||||
(1 row) |
||||
</programlisting> |
||||
|
||||
|
||||
<sect1> |
||||
<title>UNION Queries</title> |
||||
|
||||
<para> |
||||
The UNION construct is somewhat different in that it must match up |
||||
possibly dissimilar types to become a single result set. |
||||
|
||||
<procedure> |
||||
<title>UNION Evaluation</title> |
||||
|
||||
<step performance="required"> |
||||
<para> |
||||
Check for identical types for all results. |
||||
|
||||
<step performance="required"> |
||||
<para> |
||||
Coerce each result from the UNION clauses to match the type of the |
||||
first SELECT clause or the target column. |
||||
|
||||
</procedure> |
||||
|
||||
<sect2> |
||||
<title>Examples</title> |
||||
|
||||
<sect3> |
||||
<title>Underspecified Types</title> |
||||
|
||||
<para> |
||||
<programlisting> |
||||
tgl=> SELECT text 'a' AS "Text" UNION SELECT 'b'; |
||||
Text |
||||
---- |
||||
a |
||||
b |
||||
(2 rows) |
||||
</programlisting> |
||||
|
||||
<sect3> |
||||
<title>Simple UNION</title> |
||||
|
||||
<para> |
||||
<programlisting> |
||||
tgl=> SELECT 1.2 AS Float8 UNION SELECT 1; |
||||
Float8 |
||||
------ |
||||
1 |
||||
1.2 |
||||
(2 rows) |
||||
</programlisting> |
||||
|
||||
<sect3> |
||||
<title>Transposed UNION</title> |
||||
|
||||
<para> |
||||
The types of the union are forced to match the types of |
||||
the first/top clause in the union: |
||||
|
||||
<programlisting> |
||||
tgl=> SELECT 1 AS "All integers" |
||||
tgl-> UNION SELECT '2.2'::float4 |
||||
tgl-> UNION SELECT 3.3; |
||||
All integers |
||||
------------ |
||||
1 |
||||
2 |
||||
3 |
||||
(3 rows) |
||||
</programlisting> |
||||
|
||||
<para> |
||||
An alternate parser strategy could be to choose the "best" type of the bunch, but |
||||
this is more difficult because of the nice recursion technique used in the |
||||
parser. However, the "best" type is used when selecting <emphasis>into</emphasis> |
||||
a table: |
||||
|
||||
<programlisting> |
||||
tgl=> CREATE TABLE ff (f float); |
||||
CREATE |
||||
tgl=> INSERT INTO ff |
||||
tgl-> SELECT 1 |
||||
tgl-> UNION SELECT '2.2'::float4 |
||||
tgl-> UNION SELECT 3.3; |
||||
INSERT 0 3 |
||||
tgl=> SELECT f AS "Floating point" from ff; |
||||
Floating point |
||||
---------------- |
||||
1 |
||||
2.20000004768372 |
||||
3.3 |
||||
(3 rows) |
||||
</programlisting> |
||||
|
||||
</chapter> |
||||
Loading…
Reference in new issue