Sophie

Sophie

distrib > Mandriva > 10.0 > i586 > by-pkgid > db7d48fed1469a51f3fb965d5b5b2ac1 > files > 593

postgresql-docs-7.4.1-2.5.100mdk.i586.rpm

<!DOCTYPE HTML PUBLIC "-//W3C//DTD HTML 4.01 Transitional//EN">
<HTML
><HEAD
><TITLE
>Query Language (SQL) Functions</TITLE
><META
NAME="GENERATOR"
CONTENT="Modular DocBook HTML Stylesheet Version 1.7"><LINK
REV="MADE"
HREF="mailto:pgsql-docs@postgresql.org"><LINK
REL="HOME"
TITLE="PostgreSQL 7.4.1 Documentation"
HREF="index.html"><LINK
REL="UP"
TITLE="Extending SQL"
HREF="extend.html"><LINK
REL="PREVIOUS"
TITLE="User-Defined Functions"
HREF="xfunc.html"><LINK
REL="NEXT"
TITLE="Procedural Language Functions"
HREF="xfunc-pl.html"><LINK
REL="STYLESHEET"
TYPE="text/css"
HREF="stylesheet.css"><META
NAME="creation"
CONTENT="2003-12-22T03:48:47"></HEAD
><BODY
CLASS="SECT1"
><DIV
CLASS="NAVHEADER"
><TABLE
SUMMARY="Header navigation table"
WIDTH="100%"
BORDER="0"
CELLPADDING="0"
CELLSPACING="0"
><TR
><TH
COLSPAN="5"
ALIGN="center"
VALIGN="bottom"
>PostgreSQL 7.4.1 Documentation</TH
></TR
><TR
><TD
WIDTH="10%"
ALIGN="left"
VALIGN="top"
><A
HREF="xfunc.html"
ACCESSKEY="P"
>Prev</A
></TD
><TD
WIDTH="10%"
ALIGN="left"
VALIGN="top"
><A
HREF="extend.html"
>Fast Backward</A
></TD
><TD
WIDTH="60%"
ALIGN="center"
VALIGN="bottom"
>Chapter 33. Extending <ACRONYM
CLASS="ACRONYM"
>SQL</ACRONYM
></TD
><TD
WIDTH="10%"
ALIGN="right"
VALIGN="top"
><A
HREF="extend.html"
>Fast Forward</A
></TD
><TD
WIDTH="10%"
ALIGN="right"
VALIGN="top"
><A
HREF="xfunc-pl.html"
ACCESSKEY="N"
>Next</A
></TD
></TR
></TABLE
><HR
ALIGN="LEFT"
WIDTH="100%"></DIV
><DIV
CLASS="SECT1"
><H1
CLASS="SECT1"
><A
NAME="XFUNC-SQL"
>33.4. Query Language (<ACRONYM
CLASS="ACRONYM"
>SQL</ACRONYM
>) Functions</A
></H1
><A
NAME="AEN28738"
></A
><P
>    SQL functions execute an arbitrary list of SQL statements, returning
    the result of the last query in the list.
    In the simple (non-set)
    case, the first row of the last query's result will be returned.
    (Bear in mind that <SPAN
CLASS="QUOTE"
>"the first row"</SPAN
> of a multirow
    result is not well-defined unless you use <TT
CLASS="LITERAL"
>ORDER BY</TT
>.)
    If the last query happens
    to return no rows at all, the null value will be returned.
   </P
><P
>    <A
NAME="AEN28746"
></A
> Alternatively,
    an SQL function may be declared to return a set, by specifying the
    function's return type as <TT
CLASS="LITERAL"
>SETOF
    <VAR
CLASS="REPLACEABLE"
>sometype</VAR
></TT
>.<A
NAME="AEN28751"
></A
>
    In this case all rows of the last query's result are returned.
    Further details appear below.
   </P
><P
>    The body of an SQL function should be a list of one or more SQL
    statements separated by semicolons.  Note that because the syntax
    of the <TT
CLASS="COMMAND"
>CREATE FUNCTION</TT
> command requires the body of the
    function to be enclosed in single quotes, single quote marks
    (<TT
CLASS="LITERAL"
>'</TT
>) used
    in the body of the function must be escaped, by writing two single
    quotes (<TT
CLASS="LITERAL"
>''</TT
>) or a backslash (<TT
CLASS="LITERAL"
>\'</TT
>) where each
    quote is desired.
   </P
><P
>    Arguments to the SQL function may be referenced in the function
    body using the syntax <TT
CLASS="LITERAL"
>$<VAR
CLASS="REPLACEABLE"
>n</VAR
></TT
>: <TT
CLASS="LITERAL"
>$1</TT
> refers to
    the first argument, <TT
CLASS="LITERAL"
>$2</TT
> to the second, and so on.  If an argument
    is of a composite type, then the dot notation,
    e.g., <TT
CLASS="LITERAL"
>$1.name</TT
>, may be used to access attributes
    of the argument.
   </P
><DIV
CLASS="SECT2"
><H2
CLASS="SECT2"
><A
NAME="AEN28764"
>33.4.1. <ACRONYM
CLASS="ACRONYM"
>SQL</ACRONYM
> Functions on Base Types</A
></H2
><P
>     The simplest possible <ACRONYM
CLASS="ACRONYM"
>SQL</ACRONYM
> function has no arguments and
     simply returns a base type, such as <TT
CLASS="TYPE"
>integer</TT
>:
     
</P><PRE
CLASS="SCREEN"
>CREATE FUNCTION one() RETURNS integer AS '
    SELECT 1 AS result;
' LANGUAGE SQL;

SELECT one();

 one
-----
   1</PRE
><P>
    </P
><P
>     Notice that we defined a column alias within the function body for the result of the function
     (with  the  name <TT
CLASS="LITERAL"
>result</TT
>),  but this column alias is not visible
     outside the function.  Hence,  the  result  is labeled <TT
CLASS="LITERAL"
>one</TT
>
     instead of <TT
CLASS="LITERAL"
>result</TT
>.
    </P
><P
>     It is almost as easy to define <ACRONYM
CLASS="ACRONYM"
>SQL</ACRONYM
> functions  
     that take base types as arguments.  In the example below, notice
     how we refer to the arguments within the function as <TT
CLASS="LITERAL"
>$1</TT
>
     and <TT
CLASS="LITERAL"
>$2</TT
>.

</P><PRE
CLASS="SCREEN"
>CREATE FUNCTION add_em(integer, integer) RETURNS integer AS '
    SELECT $1 + $2;
' LANGUAGE SQL;

SELECT add_em(1, 2) AS answer;

 answer
--------
      3</PRE
><P>
    </P
><P
>     Here is a more useful function, which might be used to debit a
     bank account:

</P><PRE
CLASS="PROGRAMLISTING"
>CREATE FUNCTION tf1 (integer, numeric) RETURNS integer AS '
    UPDATE bank 
        SET balance = balance - $2
        WHERE accountno = $1;
    SELECT 1;
' LANGUAGE SQL;</PRE
><P>

     A user could execute this function to debit account 17 by $100.00 as
     follows:

</P><PRE
CLASS="PROGRAMLISTING"
>SELECT tf1(17, 100.0);</PRE
><P>
    </P
><P
>     In practice one would probably like a more useful result from the
     function than a constant 1, so a more likely definition
     is

</P><PRE
CLASS="PROGRAMLISTING"
>CREATE FUNCTION tf1 (integer, numeric) RETURNS numeric AS '
    UPDATE bank 
        SET balance = balance - $2
        WHERE accountno = $1;
    SELECT balance FROM bank WHERE accountno = $1;
' LANGUAGE SQL;</PRE
><P>

     which adjusts the balance and returns the new balance.
    </P
><P
>     Any collection of commands in the  <ACRONYM
CLASS="ACRONYM"
>SQL</ACRONYM
>
     language can be packaged together and defined as a function.
     Besides <TT
CLASS="COMMAND"
>SELECT</TT
> queries,
     the commands can include data modification (i.e.,
     <TT
CLASS="COMMAND"
>INSERT</TT
>, <TT
CLASS="COMMAND"
>UPDATE</TT
>, and
     <TT
CLASS="COMMAND"
>DELETE</TT
>).  However, the final command 
     must be a <TT
CLASS="COMMAND"
>SELECT</TT
> that returns whatever is
     specified as the function's return type.  Alternatively, if you
     want to define a SQL function that performs actions but has no
     useful value to return, you can define it as returning <TT
CLASS="TYPE"
>void</TT
>.
     In that case, the function body must not end with a <TT
CLASS="COMMAND"
>SELECT</TT
>.
     For example:

</P><PRE
CLASS="SCREEN"
>CREATE FUNCTION clean_emp() RETURNS void AS '
    DELETE FROM emp
        WHERE salary &lt;= 0;
' LANGUAGE SQL;

SELECT clean_emp();

 clean_emp
-----------

(1 row)</PRE
><P>
    </P
></DIV
><DIV
CLASS="SECT2"
><H2
CLASS="SECT2"
><A
NAME="AEN28795"
>33.4.2. <ACRONYM
CLASS="ACRONYM"
>SQL</ACRONYM
> Functions on Composite Types</A
></H2
><P
>     When  specifying  functions with arguments of composite
     types, we must  not  only  specify  which
     argument  we  want (as we did above with <TT
CLASS="LITERAL"
>$1</TT
> and <TT
CLASS="LITERAL"
>$2</TT
>) but
     also the attributes of  that  argument.   For  example, suppose that
     <TT
CLASS="TYPE"
>emp</TT
> is a table containing employee data, and therefore
     also the name of the composite type of each row of the table.  Here
     is a function <CODE
CLASS="FUNCTION"
>double_salary</CODE
> that computes what someone's
     salary would be if it were doubled:

</P><PRE
CLASS="SCREEN"
>CREATE TABLE emp (
    name        text,
    salary      integer,
    age         integer,
    cubicle     point
);

CREATE FUNCTION double_salary(emp) RETURNS integer AS '
    SELECT $1.salary * 2 AS salary;
' LANGUAGE SQL;

SELECT name, double_salary(emp) AS dream
    FROM emp
    WHERE emp.cubicle ~= point '(2,1)';

 name | dream
------+-------
 Sam  |  2400</PRE
><P>
    </P
><P
>     Notice the use of the syntax <TT
CLASS="LITERAL"
>$1.salary</TT
>
     to select one field of the argument row value.  Also notice
     how the calling <TT
CLASS="COMMAND"
>SELECT</TT
> command uses a table name to denote
     the entire current row of that table as a composite value.  The table
     row can alternatively be referenced like this:
</P><PRE
CLASS="SCREEN"
>SELECT name, double_salary(emp.*) AS dream
    FROM emp
    WHERE emp.cubicle ~= point '(2,1)';</PRE
><P>
     which emphasizes its row nature.
    </P
><P
>     It is also possible to build a function that returns a composite type.
     This is an example of a function 
     that returns a single <TT
CLASS="TYPE"
>emp</TT
> row:

</P><PRE
CLASS="PROGRAMLISTING"
>CREATE FUNCTION new_emp() RETURNS emp AS '
    SELECT text ''None'' AS name,
        1000 AS salary,
        25 AS age,
        point ''(2,2)'' AS cubicle;
' LANGUAGE SQL;</PRE
><P>

     In this example we have specified each of  the  attributes
     with  a  constant value, but any computation
     could have been substituted for these constants.
    </P
><P
>     Note two important things about defining the function:

     <P
></P
></P><UL
><LI
><P
>	The select list order in the query must be exactly the same as
	that in which the columns appear in the table associated
	with the composite type.  (Naming the columns, as we did above,
	is irrelevant to the system.)
       </P
></LI
><LI
><P
>	You must typecast the expressions to match the
	definition of the composite type, or you will get errors like this:
</P><PRE
CLASS="SCREEN"
><SAMP
CLASS="COMPUTEROUTPUT"
>ERROR:  function declared to return emp returns varchar instead of text at column 1</SAMP
></PRE
><P>
       </P
></LI
></UL
><P>
    </P
><P
>     A function that returns a row (composite type) can be used as a table
     function, as described below.  It can also be called in the context
     of an SQL expression, but only when you
     extract a single attribute out of the row or pass the entire row into
     another function that accepts the same composite type.
    </P
><P
>     This is an example of extracting an attribute out of a row type:

</P><PRE
CLASS="SCREEN"
>SELECT (new_emp()).name;

 name
------
 None</PRE
><P>

     We need the extra parentheses to keep the parser from getting confused:

</P><PRE
CLASS="SCREEN"
>SELECT new_emp().name;
ERROR:  syntax error at or near "." at character 17</PRE
><P>
    </P
><P
>     Another option is to use
     functional notation for extracting an attribute.  The  simple  way 
     to explain this is that we can use the
     notations <TT
CLASS="LITERAL"
>attribute(table)</TT
>  and  <TT
CLASS="LITERAL"
>table.attribute</TT
>
     interchangeably.

</P><PRE
CLASS="SCREEN"
>SELECT name(new_emp());

 name
------
 None</PRE
><P>

</P><PRE
CLASS="SCREEN"
>-- This is the same as:
-- SELECT emp.name AS youngster FROM emp WHERE emp.age &lt; 30

SELECT name(emp) AS youngster
    FROM emp
    WHERE age(emp) &lt; 30;

 youngster
-----------
 Sam</PRE
><P>
    </P
><P
>     The other way to use a function returning a row result is to declare a
     second function accepting a row type argument and pass the
     result of the first function to it:

</P><PRE
CLASS="SCREEN"
>CREATE FUNCTION getname(emp) RETURNS text AS '
    SELECT $1.name;
' LANGUAGE SQL;

SELECT getname(new_emp());
 getname
---------
 None
(1 row)</PRE
><P>
    </P
></DIV
><DIV
CLASS="SECT2"
><H2
CLASS="SECT2"
><A
NAME="AEN28830"
>33.4.3. <ACRONYM
CLASS="ACRONYM"
>SQL</ACRONYM
> Functions as Table Sources</A
></H2
><P
>     All SQL functions may be used in the <TT
CLASS="LITERAL"
>FROM</TT
> clause of a query,
     but it is particularly useful for functions returning composite types.
     If the function is defined to return a base type, the table function
     produces a one-column table.  If the function is defined to return
     a composite type, the table function produces a column for each attribute
     of the composite type.
    </P
><P
>     Here is an example:

</P><PRE
CLASS="SCREEN"
>CREATE TABLE foo (fooid int, foosubid int, fooname text);
INSERT INTO foo VALUES (1, 1, 'Joe');
INSERT INTO foo VALUES (1, 2, 'Ed');
INSERT INTO foo VALUES (2, 1, 'Mary');

CREATE FUNCTION getfoo(int) RETURNS foo AS '
    SELECT * FROM foo WHERE fooid = $1;
' LANGUAGE SQL;

SELECT *, upper(fooname) FROM getfoo(1) AS t1;

 fooid | foosubid | fooname | upper
-------+----------+---------+-------
     1 |        1 | Joe     | JOE
(2 rows)</PRE
><P>

     As the example shows, we can work with the columns of the function's
     result just the same as if they were columns of a regular table.
    </P
><P
>     Note that we only got one row out of the function.  This is because
     we did not use <TT
CLASS="LITERAL"
>SETOF</TT
>.  This is described in the next section.
    </P
></DIV
><DIV
CLASS="SECT2"
><H2
CLASS="SECT2"
><A
NAME="AEN28839"
>33.4.4. <ACRONYM
CLASS="ACRONYM"
>SQL</ACRONYM
> Functions Returning Sets</A
></H2
><P
>     When an SQL function is declared as returning <TT
CLASS="LITERAL"
>SETOF
     <VAR
CLASS="REPLACEABLE"
>sometype</VAR
></TT
>, the function's final
     <TT
CLASS="COMMAND"
>SELECT</TT
> query is executed to completion, and each row it
     outputs is returned as an element of the result set.
    </P
><P
>     This feature is normally used when calling the function in the <TT
CLASS="LITERAL"
>FROM</TT
>
     clause.  In this case each row returned by the function becomes
     a row of the table seen by the query.  For example, assume that
     table <TT
CLASS="LITERAL"
>foo</TT
> has the same contents as above, and we say:

</P><PRE
CLASS="PROGRAMLISTING"
>CREATE FUNCTION getfoo(int) RETURNS SETOF foo AS '
    SELECT * FROM foo WHERE fooid = $1;
' LANGUAGE SQL;

SELECT * FROM getfoo(1) AS t1;</PRE
><P>

     Then we would get:
</P><PRE
CLASS="SCREEN"
> fooid | foosubid | fooname
-------+----------+---------
     1 |        1 | Joe
     1 |        2 | Ed
(2 rows)</PRE
><P>
    </P
><P
>     Currently, functions returning sets may also be called in the select list
     of a query.  For each row that the query
     generates by itself, the function returning set is invoked, and an output
     row is generated for each element of the function's result set. Note,
     however, that this capability is deprecated and may be removed in future
     releases. The following is an example function returning a set from the
     select list:

</P><PRE
CLASS="SCREEN"
>CREATE FUNCTION listchildren(text) RETURNS SETOF text AS
'SELECT name FROM nodes WHERE parent = $1'
LANGUAGE SQL;

SELECT * FROM nodes;
   name    | parent
-----------+--------
 Top       |
 Child1    | Top
 Child2    | Top
 Child3    | Top
 SubChild1 | Child1
 SubChild2 | Child1
(6 rows)

SELECT listchildren('Top');
 listchildren
--------------
 Child1
 Child2
 Child3
(3 rows)

SELECT name, listchildren(name) FROM nodes;
  name  | listchildren
--------+--------------
 Top    | Child1
 Top    | Child2
 Top    | Child3
 Child1 | SubChild1
 Child1 | SubChild2
(5 rows)</PRE
><P>

     In the last <TT
CLASS="COMMAND"
>SELECT</TT
>,
     notice that no output row appears for <TT
CLASS="LITERAL"
>Child2</TT
>, <TT
CLASS="LITERAL"
>Child3</TT
>, etc.
     This happens because <CODE
CLASS="FUNCTION"
>listchildren</CODE
> returns an empty set
     for those arguments, so no result rows are generated.
    </P
></DIV
><DIV
CLASS="SECT2"
><H2
CLASS="SECT2"
><A
NAME="AEN28857"
>33.4.5. Polymorphic <ACRONYM
CLASS="ACRONYM"
>SQL</ACRONYM
> Functions</A
></H2
><P
>     <ACRONYM
CLASS="ACRONYM"
>SQL</ACRONYM
> functions may be declared to accept and
     return the polymorphic types <TT
CLASS="TYPE"
>anyelement</TT
> and
     <TT
CLASS="TYPE"
>anyarray</TT
>.  See <A
HREF="extend-type-system.html#EXTEND-TYPES-POLYMORPHIC"
>Section 33.2.5</A
> for a more detailed
     explanation of polymorphic functions. Here is a polymorphic
     function <CODE
CLASS="FUNCTION"
>make_array</CODE
> that builds up an array
     from two arbitrary data type elements:
</P><PRE
CLASS="SCREEN"
>CREATE FUNCTION make_array(anyelement, anyelement) RETURNS anyarray AS '
    SELECT ARRAY[$1, $2];
' LANGUAGE SQL;

SELECT make_array(1, 2) AS intarray, make_array('a'::text, 'b') AS textarray;
 intarray | textarray
----------+-----------
 {1,2}    | {a,b}
(1 row)</PRE
><P>
    </P
><P
>     Notice the use of the typecast <TT
CLASS="LITERAL"
>'a'::text</TT
>
     to specify that the argument is of type <TT
CLASS="TYPE"
>text</TT
>. This is
     required if the argument is just a string literal, since otherwise
     it would be treated as type
     <TT
CLASS="TYPE"
>unknown</TT
>, and array of <TT
CLASS="TYPE"
>unknown</TT
> is not a valid
     type.
     Without the typecast, you will get errors like this:
</P><PRE
CLASS="SCREEN"
><SAMP
CLASS="COMPUTEROUTPUT"
>ERROR:  could not determine "anyarray"/"anyelement" type because input has type "unknown"</SAMP
></PRE
><P>
    </P
><P
>     It is permitted to have polymorphic arguments with a deterministic
     return type, but the converse is not. For example:
</P><PRE
CLASS="SCREEN"
>CREATE FUNCTION is_greater(anyelement, anyelement) RETURNS boolean AS '
    SELECT $1 &#62; $2;
' LANGUAGE SQL;

SELECT is_greater(1, 2);
 is_greater
------------
 f
(1 row)

CREATE FUNCTION invalid_func() RETURNS anyelement AS '
    SELECT 1;
' LANGUAGE SQL;
ERROR:  cannot determine result data type
DETAIL:  A function returning "anyarray" or "anyelement" must have at least one argument of either type.</PRE
><P>
    </P
></DIV
></DIV
><DIV
CLASS="NAVFOOTER"
><HR
ALIGN="LEFT"
WIDTH="100%"><TABLE
SUMMARY="Footer navigation table"
WIDTH="100%"
BORDER="0"
CELLPADDING="0"
CELLSPACING="0"
><TR
><TD
WIDTH="33%"
ALIGN="left"
VALIGN="top"
><A
HREF="xfunc.html"
ACCESSKEY="P"
>Prev</A
></TD
><TD
WIDTH="34%"
ALIGN="center"
VALIGN="top"
><A
HREF="index.html"
ACCESSKEY="H"
>Home</A
></TD
><TD
WIDTH="33%"
ALIGN="right"
VALIGN="top"
><A
HREF="xfunc-pl.html"
ACCESSKEY="N"
>Next</A
></TD
></TR
><TR
><TD
WIDTH="33%"
ALIGN="left"
VALIGN="top"
>User-Defined Functions</TD
><TD
WIDTH="34%"
ALIGN="center"
VALIGN="top"
><A
HREF="extend.html"
ACCESSKEY="U"
>Up</A
></TD
><TD
WIDTH="33%"
ALIGN="right"
VALIGN="top"
>Procedural Language Functions</TD
></TR
></TABLE
></DIV
></BODY
></HTML
>