mirror of
https://github.com/postgres/postgres.git
synced 2025-07-30 11:03:19 +03:00
Implement SQL-spec RETURNS TABLE syntax for functions.
(Unlike the original submission, this patch treats TABLE output parameters as being entirely equivalent to OUT parameters -- tgl) Pavel Stehule
This commit is contained in:
@ -1,4 +1,4 @@
|
||||
<!-- $PostgreSQL: pgsql/doc/src/sgml/catalogs.sgml,v 2.170 2008/07/16 16:55:23 tgl Exp $ -->
|
||||
<!-- $PostgreSQL: pgsql/doc/src/sgml/catalogs.sgml,v 2.171 2008/07/18 03:32:51 tgl Exp $ -->
|
||||
<!--
|
||||
Documentation of the system catalogs, directed toward PostgreSQL developers
|
||||
-->
|
||||
@ -3680,7 +3680,8 @@
|
||||
<literal>i</literal> for <literal>IN</> arguments,
|
||||
<literal>o</literal> for <literal>OUT</> arguments,
|
||||
<literal>b</literal> for <literal>INOUT</> arguments,
|
||||
<literal>v</literal> for <literal>VARIADIC</> arguments.
|
||||
<literal>v</literal> for <literal>VARIADIC</> arguments,
|
||||
<literal>t</literal> for <literal>TABLE</> arguments.
|
||||
If all the arguments are <literal>IN</literal> arguments,
|
||||
this field will be null.
|
||||
Note that subscripts correspond to positions of
|
||||
|
@ -1,4 +1,4 @@
|
||||
<!-- $PostgreSQL: pgsql/doc/src/sgml/func.sgml,v 1.441 2008/07/16 00:48:53 momjian Exp $ -->
|
||||
<!-- $PostgreSQL: pgsql/doc/src/sgml/func.sgml,v 1.442 2008/07/18 03:32:51 tgl Exp $ -->
|
||||
|
||||
<chapter id="functions">
|
||||
<title>Functions and Operators</title>
|
||||
@ -11563,6 +11563,14 @@ SELECT pg_type_is_visible('myschema.widget'::regtype);
|
||||
<primary>pg_get_ruledef</primary>
|
||||
</indexterm>
|
||||
|
||||
<indexterm>
|
||||
<primary>pg_get_function_arguments</primary>
|
||||
</indexterm>
|
||||
|
||||
<indexterm>
|
||||
<primary>pg_get_function_result</primary>
|
||||
</indexterm>
|
||||
|
||||
<indexterm>
|
||||
<primary>pg_get_indexdef</primary>
|
||||
</indexterm>
|
||||
@ -11636,6 +11644,16 @@ SELECT pg_type_is_visible('myschema.widget'::regtype);
|
||||
<entry>decompile internal form of an expression, assuming that any Vars
|
||||
in it refer to the relation indicated by the second parameter</entry>
|
||||
</row>
|
||||
<row>
|
||||
<entry><literal><function>pg_get_function_arguments</function>(<parameter>func_oid</parameter>)</literal></entry>
|
||||
<entry><type>text</type></entry>
|
||||
<entry>get argument list for function</entry>
|
||||
</row>
|
||||
<row>
|
||||
<entry><literal><function>pg_get_function_result</function>(<parameter>func_oid</parameter>)</literal></entry>
|
||||
<entry><type>text</type></entry>
|
||||
<entry>get <literal>RETURNS</> clause for function</entry>
|
||||
</row>
|
||||
<row>
|
||||
<entry><literal><function>pg_get_indexdef</function>(<parameter>index_oid</parameter>)</literal></entry>
|
||||
<entry><type>text</type></entry>
|
||||
@ -11738,6 +11756,14 @@ SELECT pg_type_is_visible('myschema.widget'::regtype);
|
||||
the same result as the variant that does not have the parameter at all.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
<function>pg_get_function_arguments</function> returns the argument list
|
||||
of a function, in the form it would need to appear in within
|
||||
<command>CREATE FUNCTION</>.
|
||||
<function>pg_get_function_result</function> similarly returns the
|
||||
appropriate <literal>RETURNS</> clause for the function.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
<function>pg_get_serial_sequence</function> returns the name of the
|
||||
sequence associated with a column, or NULL if no sequence is associated
|
||||
|
@ -1,4 +1,4 @@
|
||||
<!-- $PostgreSQL: pgsql/doc/src/sgml/plpgsql.sgml,v 1.132 2008/07/16 01:30:21 tgl Exp $ -->
|
||||
<!-- $PostgreSQL: pgsql/doc/src/sgml/plpgsql.sgml,v 1.133 2008/07/18 03:32:51 tgl Exp $ -->
|
||||
|
||||
<chapter id="plpgsql">
|
||||
<title><application>PL/pgSQL</application> - <acronym>SQL</acronym> Procedural Language</title>
|
||||
@ -157,6 +157,8 @@
|
||||
parameters in place of an explicit specification of the return type.
|
||||
This does not add any fundamental capability to the language, but
|
||||
it is often convenient, especially for returning multiple values.
|
||||
The <literal>RETURNS TABLE</> notation can also be used in place
|
||||
of <literal>RETURNS SETOF</>.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
@ -468,6 +470,23 @@ $$ LANGUAGE plpgsql;
|
||||
<literal>RETURNS record</>.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
Another way to declare a <application>PL/pgSQL</application> function
|
||||
is with <literal>RETURNS TABLE</>, for example:
|
||||
|
||||
<programlisting>
|
||||
CREATE FUNCTION extended_sales(p_itemno int) RETURNS TABLE(quantity int, total numeric) AS $$
|
||||
BEGIN
|
||||
RETURN QUERY SELECT quantity, quantity * price FROM sales WHERE itemno = p_itemno;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
</programlisting>
|
||||
|
||||
This is exactly equivalent to declaring one or more <literal>OUT</>
|
||||
parameters and specifying <literal>RETURNS SETOF
|
||||
<replaceable>sometype</></literal>.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
When the return type of a <application>PL/pgSQL</application>
|
||||
function is declared as a polymorphic type (<type>anyelement</type>,
|
||||
|
@ -1,5 +1,5 @@
|
||||
<!--
|
||||
$PostgreSQL: pgsql/doc/src/sgml/ref/create_function.sgml,v 1.79 2008/07/16 01:30:21 tgl Exp $
|
||||
$PostgreSQL: pgsql/doc/src/sgml/ref/create_function.sgml,v 1.80 2008/07/18 03:32:52 tgl Exp $
|
||||
-->
|
||||
|
||||
<refentry id="SQL-CREATEFUNCTION">
|
||||
@ -21,7 +21,8 @@ $PostgreSQL: pgsql/doc/src/sgml/ref/create_function.sgml,v 1.79 2008/07/16 01:30
|
||||
<synopsis>
|
||||
CREATE [ OR REPLACE ] FUNCTION
|
||||
<replaceable class="parameter">name</replaceable> ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">argname</replaceable> ] <replaceable class="parameter">argtype</replaceable> [, ...] ] )
|
||||
[ RETURNS <replaceable class="parameter">rettype</replaceable> ]
|
||||
[ RETURNS <replaceable class="parameter">rettype</replaceable>
|
||||
| RETURNS TABLE ( <replaceable class="parameter">colname</replaceable> <replaceable class="parameter">coltype</replaceable> [, ...] ) ]
|
||||
{ LANGUAGE <replaceable class="parameter">langname</replaceable>
|
||||
| IMMUTABLE | STABLE | VOLATILE
|
||||
| CALLED ON NULL INPUT | RETURNS NULL ON NULL INPUT | STRICT
|
||||
@ -49,7 +50,7 @@ CREATE [ OR REPLACE ] FUNCTION
|
||||
If a schema name is included, then the function is created in the
|
||||
specified schema. Otherwise it is created in the current schema.
|
||||
The name of the new function must not match any existing function
|
||||
with the same argument types in the same schema. However,
|
||||
with the same input argument types in the same schema. However,
|
||||
functions of different argument types can share a name (this is
|
||||
called <firstterm>overloading</>).
|
||||
</para>
|
||||
@ -104,6 +105,9 @@ CREATE [ OR REPLACE ] FUNCTION
|
||||
The mode of an argument: <literal>IN</>, <literal>OUT</>,
|
||||
<literal>INOUT</>, or <literal>VARIADIC</>.
|
||||
If omitted, the default is <literal>IN</>.
|
||||
Only <literal>OUT</> arguments can follow a <literal>VARIADIC</> one.
|
||||
Also, <literal>OUT</> and <literal>INOUT</> arguments cannot be used
|
||||
together with the <literal>RETURNS TABLE</> notation.
|
||||
</para>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
@ -183,6 +187,30 @@ CREATE [ OR REPLACE ] FUNCTION
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
<varlistentry>
|
||||
<term><replaceable class="parameter">colname</replaceable></term>
|
||||
|
||||
<listitem>
|
||||
<para>
|
||||
The name of an output column in the <literal>RETURNS TABLE</>
|
||||
syntax. This is effectively another way of declaring a named
|
||||
<literal>OUT</> parameter, except that <literal>RETURNS TABLE</>
|
||||
also implies <literal>RETURNS SETOF</>.
|
||||
</para>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
<varlistentry>
|
||||
<term><replaceable class="parameter">coltype</replaceable></term>
|
||||
|
||||
<listitem>
|
||||
<para>
|
||||
The data type of an output column in the <literal>RETURNS TABLE</>
|
||||
syntax.
|
||||
</para>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
<varlistentry>
|
||||
<term><replaceable class="parameter">langname</replaceable></term>
|
||||
|
||||
@ -437,7 +465,7 @@ CREATE [ OR REPLACE ] FUNCTION
|
||||
<productname>PostgreSQL</productname> allows function
|
||||
<firstterm>overloading</firstterm>; that is, the same name can be
|
||||
used for several different functions so long as they have distinct
|
||||
argument types. However, the C names of all functions must be
|
||||
input argument types. However, the C names of all functions must be
|
||||
different, so you must give overloaded C functions different C
|
||||
names (for example, use the argument types as part of the C
|
||||
names).
|
||||
@ -541,6 +569,18 @@ CREATE FUNCTION dup(int) RETURNS dup_result
|
||||
|
||||
SELECT * FROM dup(42);
|
||||
</programlisting>
|
||||
Another way to return multiple columns is to use a <literal>TABLE</>
|
||||
function:
|
||||
<programlisting>
|
||||
CREATE FUNCTION dup(int) RETURNS TABLE(f1 int, f2 text)
|
||||
AS $$ SELECT $1, CAST($1 AS text) || ' is text' $$
|
||||
LANGUAGE SQL;
|
||||
|
||||
SELECT * FROM dup(42);
|
||||
</programlisting>
|
||||
However, a <literal>TABLE</> function is different from the
|
||||
preceding examples, because it actually returns a <emphasis>set</>
|
||||
of records, not just one record.
|
||||
</para>
|
||||
</refsect1>
|
||||
|
||||
|
@ -1,4 +1,4 @@
|
||||
<!-- $PostgreSQL: pgsql/doc/src/sgml/xfunc.sgml,v 1.131 2008/07/16 01:30:21 tgl Exp $ -->
|
||||
<!-- $PostgreSQL: pgsql/doc/src/sgml/xfunc.sgml,v 1.132 2008/07/18 03:32:52 tgl Exp $ -->
|
||||
|
||||
<sect1 id="xfunc">
|
||||
<title>User-Defined Functions</title>
|
||||
@ -94,11 +94,12 @@
|
||||
</para>
|
||||
|
||||
<para>
|
||||
<indexterm><primary>SETOF</><seealso>function</></> Alternatively,
|
||||
an SQL function can be declared to return a set, by specifying the
|
||||
function's return type as <literal>SETOF
|
||||
<replaceable>sometype</></literal>. In this case all rows of the
|
||||
last query's result are returned. Further details appear below.
|
||||
Alternatively, an SQL function can be declared to return a set,
|
||||
by specifying the function's return type as <literal>SETOF
|
||||
<replaceable>sometype</></literal>, or equivalently by declaring it as
|
||||
<literal>RETURNS TABLE(<replaceable>columns</>)</literal>. In this case
|
||||
all rows of the last query's result are returned. Further details appear
|
||||
below.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
@ -117,7 +118,7 @@
|
||||
other SQL commands. (The only exception is that you cannot put
|
||||
<command>BEGIN</>, <command>COMMIT</>, <command>ROLLBACK</>, or
|
||||
<command>SAVEPOINT</> commands into a <acronym>SQL</acronym> function.)
|
||||
However, the final command
|
||||
However, the final command
|
||||
must be a <command>SELECT</command> 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
|
||||
@ -175,7 +176,7 @@ INSERT INTO $1 VALUES (42);
|
||||
<para>
|
||||
The simplest possible <acronym>SQL</acronym> function has no arguments and
|
||||
simply returns a base type, such as <type>integer</type>:
|
||||
|
||||
|
||||
<screen>
|
||||
CREATE FUNCTION one() RETURNS integer AS $$
|
||||
SELECT 1 AS result;
|
||||
@ -202,7 +203,7 @@ SELECT one();
|
||||
</para>
|
||||
|
||||
<para>
|
||||
It is almost as easy to define <acronym>SQL</acronym> functions
|
||||
It is almost as easy to define <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 <literal>$1</>
|
||||
and <literal>$2</>.
|
||||
@ -226,7 +227,7 @@ SELECT add_em(1, 2) AS answer;
|
||||
|
||||
<programlisting>
|
||||
CREATE FUNCTION tf1 (integer, numeric) RETURNS integer AS $$
|
||||
UPDATE bank
|
||||
UPDATE bank
|
||||
SET balance = balance - $2
|
||||
WHERE accountno = $1;
|
||||
SELECT 1;
|
||||
@ -248,7 +249,7 @@ SELECT tf1(17, 100.0);
|
||||
|
||||
<programlisting>
|
||||
CREATE FUNCTION tf1 (integer, numeric) RETURNS numeric AS $$
|
||||
UPDATE bank
|
||||
UPDATE bank
|
||||
SET balance = balance - $2
|
||||
WHERE accountno = $1;
|
||||
SELECT balance FROM bank WHERE accountno = $1;
|
||||
@ -267,7 +268,7 @@ $$ LANGUAGE SQL;
|
||||
types, we must not only specify which
|
||||
argument we want (as we did above with <literal>$1</> and <literal>$2</literal>) but
|
||||
also the desired attribute (field) of that argument. For example,
|
||||
suppose that
|
||||
suppose that
|
||||
<type>emp</type> 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 <function>double_salary</function> that computes what someone's
|
||||
@ -323,7 +324,7 @@ SELECT name, double_salary(ROW(name, salary*1.1, age, cubicle)) AS dream
|
||||
|
||||
<para>
|
||||
It is also possible to build a function that returns a composite type.
|
||||
This is an example of a function
|
||||
This is an example of a function
|
||||
that returns a single <type>emp</type> row:
|
||||
|
||||
<programlisting>
|
||||
@ -364,7 +365,7 @@ ERROR: function declared to return emp returns varchar instead of text at colum
|
||||
</para>
|
||||
</listitem>
|
||||
</itemizedlist>
|
||||
</para>
|
||||
</para>
|
||||
|
||||
<para>
|
||||
A different way to define the same function is:
|
||||
@ -380,7 +381,7 @@ $$ LANGUAGE SQL;
|
||||
in this situation, but it is a handy alternative in some cases
|
||||
— for example, if we need to compute the result by calling
|
||||
another function that returns the desired composite value.
|
||||
</para>
|
||||
</para>
|
||||
|
||||
<para>
|
||||
We could call this function directly in either of two ways:
|
||||
@ -401,7 +402,7 @@ SELECT * FROM new_emp();
|
||||
|
||||
The second way is described more fully in <xref
|
||||
linkend="xfunc-sql-table-functions">.
|
||||
</para>
|
||||
</para>
|
||||
|
||||
<para>
|
||||
When you use a function that returns a composite type,
|
||||
@ -429,7 +430,7 @@ LINE 1: SELECT new_emp().name;
|
||||
|
||||
<para>
|
||||
Another option is to use
|
||||
functional notation for extracting an attribute. The simple way
|
||||
functional notation for extracting an attribute. The simple way
|
||||
to explain this is that we can use the
|
||||
notations <literal>attribute(table)</> and <literal>table.attribute</>
|
||||
interchangeably.
|
||||
@ -693,9 +694,14 @@ SELECT *, upper(fooname) FROM getfoo(1) AS t1;
|
||||
</para>
|
||||
</sect2>
|
||||
|
||||
<sect2>
|
||||
<sect2 id="xfunc-sql-functions-returning-set">
|
||||
<title><acronym>SQL</acronym> Functions Returning Sets</title>
|
||||
|
||||
<indexterm>
|
||||
<primary>function</primary>
|
||||
<secondary>with SETOF</secondary>
|
||||
</indexterm>
|
||||
|
||||
<para>
|
||||
When an SQL function is declared as returning <literal>SETOF
|
||||
<replaceable>sometype</></literal>, the function's final
|
||||
@ -733,7 +739,7 @@ SELECT * FROM getfoo(1) AS t1;
|
||||
|
||||
<programlisting>
|
||||
CREATE FUNCTION sum_n_product_with_tab (x int, OUT sum int, OUT product int) RETURNS SETOF record AS $$
|
||||
SELECT x + tab.y, x * tab.y FROM tab;
|
||||
SELECT $1 + tab.y, $1 * tab.y FROM tab;
|
||||
$$ LANGUAGE SQL;
|
||||
</programlisting>
|
||||
|
||||
@ -794,6 +800,41 @@ SELECT name, listchildren(name) FROM nodes;
|
||||
</para>
|
||||
</sect2>
|
||||
|
||||
<sect2 id="xfunc-sql-functions-returning-table">
|
||||
<title><acronym>SQL</acronym> Functions Returning <literal>TABLE</></title>
|
||||
|
||||
<indexterm>
|
||||
<primary>function</primary>
|
||||
<secondary>RETURNS TABLE</secondary>
|
||||
</indexterm>
|
||||
|
||||
<para>
|
||||
There is another way to declare a function as returning a set,
|
||||
which is to use the syntax
|
||||
<literal>RETURNS TABLE(<replaceable>columns</>)</literal>.
|
||||
This is equivalent to using one or more <literal>OUT</> parameters plus
|
||||
marking the function as returning <literal>SETOF record</> (or
|
||||
<literal>SETOF</> a single output parameter's type, as appropriate).
|
||||
This notation is specified in recent versions of the SQL standard, and
|
||||
thus may be more portable than using <literal>SETOF</>.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
For example, the preceding sum-and-product example could also be
|
||||
done this way:
|
||||
|
||||
<programlisting>
|
||||
CREATE FUNCTION sum_n_product_with_tab (x int) RETURNS TABLE(sum int, product int) AS $$
|
||||
SELECT $1 + tab.y, $1 * tab.y FROM tab;
|
||||
$$ LANGUAGE SQL;
|
||||
</programlisting>
|
||||
|
||||
It is not allowed to use explicit <literal>OUT</> or <literal>INOUT</>
|
||||
parameters with the <literal>RETURNS TABLE</> notation — you must
|
||||
put all the output columns in the <literal>TABLE</> list.
|
||||
</para>
|
||||
</sect2>
|
||||
|
||||
<sect2>
|
||||
<title>Polymorphic <acronym>SQL</acronym> Functions</title>
|
||||
|
||||
|
Reference in New Issue
Block a user