From 69a785b8bfe076847f72317a41964821e85ccfd6 Mon Sep 17 00:00:00 2001 From: Tom Lane Date: Fri, 18 Jul 2008 03:32:53 +0000 Subject: 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 --- doc/src/sgml/catalogs.sgml | 5 ++- doc/src/sgml/func.sgml | 28 ++++++++++++- doc/src/sgml/plpgsql.sgml | 21 +++++++++- doc/src/sgml/ref/create_function.sgml | 48 +++++++++++++++++++-- doc/src/sgml/xfunc.sgml | 79 ++++++++++++++++++++++++++--------- 5 files changed, 154 insertions(+), 27 deletions(-) (limited to 'doc/src') diff --git a/doc/src/sgml/catalogs.sgml b/doc/src/sgml/catalogs.sgml index 83be70ca666..a7a3cea9068 100644 --- a/doc/src/sgml/catalogs.sgml +++ b/doc/src/sgml/catalogs.sgml @@ -1,4 +1,4 @@ - + @@ -3680,7 +3680,8 @@ i for IN arguments, o for OUT arguments, b for INOUT arguments, - v for VARIADIC arguments. + v for VARIADIC arguments, + t for TABLE arguments. If all the arguments are IN arguments, this field will be null. Note that subscripts correspond to positions of diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml index acd2b92918e..fb77ae43ea4 100644 --- a/doc/src/sgml/func.sgml +++ b/doc/src/sgml/func.sgml @@ -1,4 +1,4 @@ - + Functions and Operators @@ -11563,6 +11563,14 @@ SELECT pg_type_is_visible('myschema.widget'::regtype); pg_get_ruledef + + pg_get_function_arguments + + + + pg_get_function_result + + pg_get_indexdef @@ -11636,6 +11644,16 @@ SELECT pg_type_is_visible('myschema.widget'::regtype); decompile internal form of an expression, assuming that any Vars in it refer to the relation indicated by the second parameter + + pg_get_function_arguments(func_oid) + text + get argument list for function + + + pg_get_function_result(func_oid) + text + get RETURNS clause for function + pg_get_indexdef(index_oid) text @@ -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. + + pg_get_function_arguments returns the argument list + of a function, in the form it would need to appear in within + CREATE FUNCTION. + pg_get_function_result similarly returns the + appropriate RETURNS clause for the function. + + pg_get_serial_sequence returns the name of the sequence associated with a column, or NULL if no sequence is associated diff --git a/doc/src/sgml/plpgsql.sgml b/doc/src/sgml/plpgsql.sgml index 42bd6048b68..e47142078c0 100644 --- a/doc/src/sgml/plpgsql.sgml +++ b/doc/src/sgml/plpgsql.sgml @@ -1,4 +1,4 @@ - + <application>PL/pgSQL</application> - <acronym>SQL</acronym> Procedural Language @@ -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 RETURNS TABLE notation can also be used in place + of RETURNS SETOF. @@ -468,6 +470,23 @@ $$ LANGUAGE plpgsql; RETURNS record. + + Another way to declare a PL/pgSQL function + is with RETURNS TABLE, for example: + + +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; + + + This is exactly equivalent to declaring one or more OUT + parameters and specifying RETURNS SETOF + sometype. + + When the return type of a PL/pgSQL function is declared as a polymorphic type (anyelement, diff --git a/doc/src/sgml/ref/create_function.sgml b/doc/src/sgml/ref/create_function.sgml index 18b9bf7beea..b6f9c015c55 100644 --- a/doc/src/sgml/ref/create_function.sgml +++ b/doc/src/sgml/ref/create_function.sgml @@ -1,5 +1,5 @@ @@ -21,7 +21,8 @@ $PostgreSQL: pgsql/doc/src/sgml/ref/create_function.sgml,v 1.79 2008/07/16 01:30 CREATE [ OR REPLACE ] FUNCTION name ( [ [ argmode ] [ argname ] argtype [, ...] ] ) - [ RETURNS rettype ] + [ RETURNS rettype + | RETURNS TABLE ( colname coltype [, ...] ) ] { LANGUAGE langname | 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 overloading). @@ -104,6 +105,9 @@ CREATE [ OR REPLACE ] FUNCTION The mode of an argument: IN, OUT, INOUT, or VARIADIC. If omitted, the default is IN. + Only OUT arguments can follow a VARIADIC one. + Also, OUT and INOUT arguments cannot be used + together with the RETURNS TABLE notation. @@ -183,6 +187,30 @@ CREATE [ OR REPLACE ] FUNCTION + + colname + + + + The name of an output column in the RETURNS TABLE + syntax. This is effectively another way of declaring a named + OUT parameter, except that RETURNS TABLE + also implies RETURNS SETOF. + + + + + + coltype + + + + The data type of an output column in the RETURNS TABLE + syntax. + + + + langname @@ -437,7 +465,7 @@ CREATE [ OR REPLACE ] FUNCTION PostgreSQL allows function overloading; 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); + Another way to return multiple columns is to use a TABLE + function: + +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); + + However, a TABLE function is different from the + preceding examples, because it actually returns a set + of records, not just one record. diff --git a/doc/src/sgml/xfunc.sgml b/doc/src/sgml/xfunc.sgml index 55ed719ec64..26567334316 100644 --- a/doc/src/sgml/xfunc.sgml +++ b/doc/src/sgml/xfunc.sgml @@ -1,4 +1,4 @@ - + User-Defined Functions @@ -94,11 +94,12 @@ - SETOFfunction Alternatively, - an SQL function can be declared to return a set, by specifying the - function's return type as SETOF - sometype. 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 SETOF + sometype, or equivalently by declaring it as + RETURNS TABLE(columns). In this case + all rows of the last query's result are returned. Further details appear + below. @@ -117,7 +118,7 @@ other SQL commands. (The only exception is that you cannot put BEGIN, COMMIT, ROLLBACK, or SAVEPOINT commands into a SQL function.) - However, the final command + However, the final command must be a SELECT 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); The simplest possible SQL function has no arguments and simply returns a base type, such as integer: - + CREATE FUNCTION one() RETURNS integer AS $$ SELECT 1 AS result; @@ -202,7 +203,7 @@ SELECT one(); - It is almost as easy to define SQL functions + It is almost as easy to define SQL functions that take base types as arguments. In the example below, notice how we refer to the arguments within the function as $1 and $2. @@ -226,7 +227,7 @@ SELECT add_em(1, 2) AS answer; 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); 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 $1 and $2) but also the desired attribute (field) of that argument. For example, - suppose that + suppose that emp 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 double_salary that computes what someone's @@ -323,7 +324,7 @@ SELECT name, double_salary(ROW(name, salary*1.1, age, cubicle)) AS dream 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 emp row: @@ -364,7 +365,7 @@ ERROR: function declared to return emp returns varchar instead of text at colum - + 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. - + 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 . - + When you use a function that returns a composite type, @@ -429,7 +430,7 @@ LINE 1: SELECT new_emp().name; 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 attribute(table) and table.attribute interchangeably. @@ -693,9 +694,14 @@ SELECT *, upper(fooname) FROM getfoo(1) AS t1; - + <acronym>SQL</acronym> Functions Returning Sets + + function + with SETOF + + When an SQL function is declared as returning SETOF sometype, the function's final @@ -733,7 +739,7 @@ SELECT * FROM getfoo(1) AS t1; 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; @@ -794,6 +800,41 @@ SELECT name, listchildren(name) FROM nodes; + + <acronym>SQL</acronym> Functions Returning <literal>TABLE</> + + + function + RETURNS TABLE + + + + There is another way to declare a function as returning a set, + which is to use the syntax + RETURNS TABLE(columns). + This is equivalent to using one or more OUT parameters plus + marking the function as returning SETOF record (or + 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 SETOF. + + + + For example, the preceding sum-and-product example could also be + done this way: + + +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; + + + It is not allowed to use explicit OUT or INOUT + parameters with the RETURNS TABLE notation — you must + put all the output columns in the TABLE list. + + + Polymorphic <acronym>SQL</acronym> Functions -- cgit v1.2.3