Commit e00ee887 authored by Tom Lane's avatar Tom Lane

Allow plpgsql functions to omit RETURN command when the function returns

output parameters or VOID or a set.  There seems no particular reason to
insist on a RETURN in these cases, since the function return value is
determined by other elements anyway.  Per recent discussion.
parent 5c7c017b
<!--
$PostgreSQL: pgsql/doc/src/sgml/plpgsql.sgml,v 1.64 2005/04/05 18:05:45 tgl Exp $
$PostgreSQL: pgsql/doc/src/sgml/plpgsql.sgml,v 1.65 2005/04/07 14:53:04 tgl Exp $
-->
<chapter id="plpgsql">
......@@ -123,14 +123,14 @@ $$ LANGUAGE plpgsql;
<para>
Because <application>PL/pgSQL</application> saves execution plans
in this way, SQL commands that appear directly in a
<application>PL/pgSQL</application> function must refer to the
same tables and columns on every execution; that is, you cannot use
a parameter as the name of a table or column in an SQL command. To get
around this restriction, you can construct dynamic commands using
the <application>PL/pgSQL</application> <command>EXECUTE</command>
statement &mdash; at the price of constructing a new execution plan on
every execution.
in this way, SQL commands that appear directly in a
<application>PL/pgSQL</application> function must refer to the
same tables and columns on every execution; that is, you cannot use
a parameter as the name of a table or column in an SQL command. To get
around this restriction, you can construct dynamic commands using
the <application>PL/pgSQL</application> <command>EXECUTE</command>
statement &mdash; at the price of constructing a new execution plan on
every execution.
</para>
<note>
......@@ -673,7 +673,6 @@ $$ LANGUAGE plpgsql;
CREATE FUNCTION sales_tax(subtotal real, OUT tax real) AS $$
BEGIN
tax := subtotal * 0.06;
RETURN;
END;
$$ LANGUAGE plpgsql;
</programlisting>
......@@ -691,7 +690,6 @@ CREATE FUNCTION sum_n_product(x int, y int, OUT sum int, OUT prod int) AS $$
BEGIN
sum := x + y;
prod := x * y;
RETURN;
END;
$$ LANGUAGE plpgsql;
</programlisting>
......@@ -742,7 +740,6 @@ CREATE FUNCTION add_three_values(v1 anyelement, v2 anyelement, v3 anyelement,
AS $$
BEGIN
sum := v1 + v2 + v3;
RETURN;
END;
$$ LANGUAGE plpgsql;
</programlisting>
......@@ -1498,17 +1495,20 @@ RETURN <replaceable>expression</replaceable>;
</para>
<para>
The return value of a function cannot be left undefined. If
control reaches the end of the top-level block of the function
without hitting a <command>RETURN</command> statement, a run-time
error will occur.
If you declared the function to return <type>void</type>, a
<command>RETURN</command> statement can be used to exit the function
early; but do not write an expression following
<command>RETURN</command>.
</para>
<para>
If you have declared the function to
return <type>void</type>, a <command>RETURN</command> statement
must still be provided; but in this case the expression following
<command>RETURN</command> is optional and will be ignored if present.
The return value of a function cannot be left undefined. If
control reaches the end of the top-level block of the function
without hitting a <command>RETURN</command> statement, a run-time
error will occur. This restriction does not apply to functions
with output parameters and functions returning <type>void</type>,
however. In those cases a <command>RETURN</command> statement is
automatically executed if the top-level block finishes.
</para>
</sect3>
......@@ -1538,7 +1538,8 @@ RETURN NEXT <replaceable>expression</replaceable>;
the <application>PL/pgSQL</> function. As successive
<command>RETURN NEXT</command> commands are executed, the result
set is built up. A final <command>RETURN</command>, which should
have no argument, causes control to exit the function.
have no argument, causes control to exit the function (or you can
just let control reach the end of the function).
</para>
<para>
......@@ -2424,7 +2425,6 @@ BEGIN
RETURN NEXT $1;
OPEN $2 FOR SELECT * FROM table_2;
RETURN NEXT $2;
RETURN;
END;
$$ LANGUAGE plpgsql;
......@@ -2990,7 +2990,8 @@ AFTER INSERT OR UPDATE OR DELETE ON sales_fact
<listitem>
<para>
In <productname>PostgreSQL</> you need to use dollar quoting or escape
In <productname>PostgreSQL</> the function body has to be written as
a string literal. Therefore you need to use dollar quoting or escape
single quotes in the function body. See <xref
linkend="plpgsql-quote-tips">.
</para>
......@@ -3027,8 +3028,8 @@ AFTER INSERT OR UPDATE OR DELETE ON sales_fact
<para>
Here is an <productname>Oracle</productname> <application>PL/SQL</> function:
<programlisting>
CREATE OR REPLACE FUNCTION cs_fmt_browser_version(v_name IN varchar,
v_version IN varchar)
CREATE OR REPLACE FUNCTION cs_fmt_browser_version(v_name varchar,
v_version varchar)
RETURN varchar IS
BEGIN
IF v_version IS NULL THEN
......@@ -3042,21 +3043,10 @@ show errors;
</para>
<para>
Let's go through this function and see the differences to <application>PL/pgSQL</>:
Let's go through this function and see the differences compared to
<application>PL/pgSQL</>:
<itemizedlist>
<listitem>
<para>
<productname>Oracle</productname> can have
<literal>IN</literal>, <literal>OUT</literal>, and
<literal>INOUT</literal> parameters passed to functions.
<literal>INOUT</literal>, for example, means that the
parameter will receive a value and return
another. <productname>PostgreSQL</> only has <literal>IN</literal>
parameters, and hence there is no specification of the parameter kind.
</para>
</listitem>
<listitem>
<para>
The <literal>RETURN</literal> key word in the function
......@@ -3187,7 +3177,6 @@ BEGIN
|| ' LANGUAGE plpgsql;' ;
EXECUTE func_cmd;
RETURN;
END;
$func$ LANGUAGE plpgsql;
</programlisting>
......@@ -3209,8 +3198,8 @@ $func$ LANGUAGE plpgsql;
<para>
<xref linkend="plpgsql-porting-ex3"> shows how to port a function
with <literal>OUT</> parameters and string manipulation.
<productname>PostgreSQL</> does not have an
<function>instr</function> function, but you can work around it
<productname>PostgreSQL</> does not have a built-in
<function>instr</function> function, but you can create one
using a combination of other
functions.<indexterm><primary>instr</></indexterm> In <xref
linkend="plpgsql-porting-appendix"> there is a
......@@ -3227,9 +3216,6 @@ $func$ LANGUAGE plpgsql;
<para>
The following <productname>Oracle</productname> PL/SQL procedure is used
to parse a URL and return several elements (host, path, and query).
In <productname>PostgreSQL</>, functions can return only one value.
One way to work around this is to make the return value a composite
type (row type).
</para>
<para>
......@@ -3278,45 +3264,41 @@ show errors;
<para>
Here is a possible translation into <application>PL/pgSQL</>:
<programlisting>
CREATE TYPE cs_parse_url_result AS (
v_host VARCHAR,
v_path VARCHAR,
v_query VARCHAR
);
CREATE OR REPLACE FUNCTION cs_parse_url(v_url VARCHAR)
RETURNS cs_parse_url_result AS $$
CREATE OR REPLACE FUNCTION cs_parse_url(
v_url IN VARCHAR,
v_host OUT VARCHAR, -- This will be passed back
v_path OUT VARCHAR, -- This one too
v_query OUT VARCHAR) -- And this one
AS $$
DECLARE
res cs_parse_url_result;
a_pos1 INTEGER;
a_pos2 INTEGER;
BEGIN
res.v_host := NULL;
res.v_path := NULL;
res.v_query := NULL;
v_host := NULL;
v_path := NULL;
v_query := NULL;
a_pos1 := instr(v_url, '//');
IF a_pos1 = 0 THEN
RETURN res;
RETURN;
END IF;
a_pos2 := instr(v_url, '/', a_pos1 + 2);
IF a_pos2 = 0 THEN
res.v_host := substr(v_url, a_pos1 + 2);
res.v_path := '/';
RETURN res;
v_host := substr(v_url, a_pos1 + 2);
v_path := '/';
RETURN;
END IF;
res.v_host := substr(v_url, a_pos1 + 2, a_pos2 - a_pos1 - 2);
v_host := substr(v_url, a_pos1 + 2, a_pos2 - a_pos1 - 2);
a_pos1 := instr(v_url, '?', a_pos2 + 1);
IF a_pos1 = 0 THEN
res.v_path := substr(v_url, a_pos2);
RETURN res;
v_path := substr(v_url, a_pos2);
RETURN;
END IF;
res.v_path := substr(v_url, a_pos2, a_pos1 - a_pos2);
res.v_query := substr(v_url, a_pos1 + 1);
RETURN res;
v_path := substr(v_url, a_pos2, a_pos1 - a_pos2);
v_query := substr(v_url, a_pos1 + 1);
END;
$$ LANGUAGE plpgsql;
</programlisting>
......@@ -3427,8 +3409,6 @@ BEGIN
WHEN unique_violation THEN <co id="co.plpgsql-porting-exception">
-- don't worry if it already exists
END;
RETURN;
END;
$$ LANGUAGE plpgsql;
</programlisting>
......
......@@ -4,7 +4,7 @@
* procedural language
*
* IDENTIFICATION
* $PostgreSQL: pgsql/src/pl/plpgsql/src/gram.y,v 1.68 2005/04/05 18:05:46 tgl Exp $
* $PostgreSQL: pgsql/src/pl/plpgsql/src/gram.y,v 1.69 2005/04/07 14:53:04 tgl Exp $
*
* This software is copyrighted by Jan Wieck - Hamburg.
*
......@@ -1071,7 +1071,7 @@ stmt_return : K_RETURN lno
else if (plpgsql_curr_compile->fn_rettype == VOIDOID)
{
if (yylex() != ';')
yyerror("function returning void cannot specify RETURN expression");
yyerror("RETURN cannot have a parameter in function returning void");
}
else if (plpgsql_curr_compile->fn_retistuple)
{
......
......@@ -3,7 +3,7 @@
* procedural language
*
* IDENTIFICATION
* $PostgreSQL: pgsql/src/pl/plpgsql/src/pl_comp.c,v 1.86 2005/04/05 06:22:16 tgl Exp $
* $PostgreSQL: pgsql/src/pl/plpgsql/src/pl_comp.c,v 1.87 2005/04/07 14:53:04 tgl Exp $
*
* This software is copyrighted by Jan Wieck - Hamburg.
*
......@@ -271,8 +271,8 @@ do_compile(FunctionCallInfo fcinfo,
int parse_rc;
Oid rettypeid;
int numargs;
int num_in_args;
int num_out_args;
int num_in_args = 0;
int num_out_args = 0;
Oid *argtypes;
char **argnames;
char *argmodes;
......@@ -374,7 +374,6 @@ do_compile(FunctionCallInfo fcinfo,
/*
* Create the variables for the procedure's parameters.
*/
num_in_args = num_out_args = 0;
for (i = 0; i < numargs; i++)
{
char buf[32];
......@@ -641,12 +640,48 @@ do_compile(FunctionCallInfo fcinfo,
parse_rc = plpgsql_yyparse();
if (parse_rc != 0)
elog(ERROR, "plpgsql parser returned %d", parse_rc);
function->action = plpgsql_yylval.program;
plpgsql_scanner_finish();
pfree(proc_source);
/*
* If that was successful, complete the function's info.
* If it has OUT parameters or returns VOID or returns a set, we allow
* control to fall off the end without an explicit RETURN statement.
* The easiest way to implement this is to add a RETURN statement to the
* end of the statement list during parsing. However, if the outer block
* has an EXCEPTION clause, we need to make a new outer block, since the
* added RETURN shouldn't act like it is inside the EXCEPTION clause.
*/
if (num_out_args > 0 || function->fn_rettype == VOIDOID ||
function->fn_retset)
{
if (function->action->exceptions != NIL)
{
PLpgSQL_stmt_block *new;
new = palloc0(sizeof(PLpgSQL_stmt_block));
new->cmd_type = PLPGSQL_STMT_BLOCK;
new->body = list_make1(function->action);
function->action = new;
}
if (function->action->body == NIL ||
((PLpgSQL_stmt *) llast(function->action->body))->cmd_type != PLPGSQL_STMT_RETURN)
{
PLpgSQL_stmt_return *new;
new = palloc0(sizeof(PLpgSQL_stmt_return));
new->cmd_type = PLPGSQL_STMT_RETURN;
new->expr = NULL;
new->retvarno = function->out_param_varno;
function->action->body = lappend(function->action->body, new);
}
}
/*
* Complete the function's info
*/
function->fn_nargs = procStruct->pronargs;
for (i = 0; i < function->fn_nargs; i++)
......@@ -655,7 +690,6 @@ do_compile(FunctionCallInfo fcinfo,
function->datums = palloc(sizeof(PLpgSQL_datum *) * plpgsql_nDatums);
for (i = 0; i < plpgsql_nDatums; i++)
function->datums[i] = plpgsql_Datums[i];
function->action = plpgsql_yylval.program;
/* Debug dump for completed functions */
if (plpgsql_DumpExecTree)
......
......@@ -3,7 +3,7 @@
* procedural language
*
* IDENTIFICATION
* $PostgreSQL: pgsql/src/pl/plpgsql/src/pl_exec.c,v 1.134 2005/04/05 06:22:16 tgl Exp $
* $PostgreSQL: pgsql/src/pl/plpgsql/src/pl_exec.c,v 1.135 2005/04/07 14:53:04 tgl Exp $
*
* This software is copyrighted by Jan Wieck - Hamburg.
*
......@@ -1691,12 +1691,18 @@ exec_stmt_return(PLpgSQL_execstate *estate, PLpgSQL_stmt_return *stmt)
&(estate->retisnull),
&(estate->rettype));
}
return PLPGSQL_RC_RETURN;
}
/*
* Special hack for function returning VOID: instead of NULL, return a
* non-null VOID value. This is of dubious importance but is kept for
* backwards compatibility. Note that the only other way to get here
* is to have written "RETURN NULL" in a function returning tuple.
*/
if (estate->fn_rettype == VOIDOID)
{
/* Special hack for function returning VOID */
Assert(stmt->retvarno < 0 && stmt->expr == NULL);
estate->retval = (Datum) 0;
estate->retisnull = false;
estate->rettype = VOIDOID;
......
......@@ -1739,7 +1739,8 @@ SELECT * FROM test_ret_rec_dyn(5) AS (a int, b numeric, c text);
(1 row)
--
-- Test handling of OUT parameters, including polymorphic cases
-- Test handling of OUT parameters, including polymorphic cases.
-- Note that RETURN is optional with OUT params; we try both ways.
--
-- wrong way to do it:
create function f1(in i int, out j int) returns int as $$
......@@ -1769,7 +1770,6 @@ select * from f1(42);
create or replace function f1(inout i int) as $$
begin
i := i+1;
return;
end$$ language plpgsql;
select f1(42);
f1
......@@ -1805,7 +1805,6 @@ begin
j := i;
j := j+1;
k := 'foo';
return;
end$$ language plpgsql;
select f1(42);
f1
......@@ -1828,7 +1827,6 @@ begin
j := j+1;
k := 'foot';
return next;
return;
end$$ language plpgsql;
select * from f1(42);
j | k
......@@ -2358,6 +2356,27 @@ create function void_return_expr() returns void as $$
begin
return 5;
end;$$ language plpgsql;
ERROR: function returning void cannot specify RETURN expression at or near "5" at character 72
ERROR: RETURN cannot have a parameter in function returning void at or near "5" at character 72
LINE 3: return 5;
^
-- VOID functions are allowed to omit RETURN
create function void_return_expr() returns void as $$
begin
perform 2+2;
end;$$ language plpgsql;
select void_return_expr();
void_return_expr
------------------
(1 row)
-- but ordinary functions are not
create function missing_return_expr() returns int as $$
begin
perform 2+2;
end;$$ language plpgsql;
select missing_return_expr();
ERROR: control reached end of function without RETURN
CONTEXT: PL/pgSQL function "missing_return_expr"
drop function void_return_expr();
drop function missing_return_expr();
......@@ -1561,7 +1561,8 @@ SELECT * FROM test_ret_rec_dyn(1500) AS (a int, b int, c int);
SELECT * FROM test_ret_rec_dyn(5) AS (a int, b numeric, c text);
--
-- Test handling of OUT parameters, including polymorphic cases
-- Test handling of OUT parameters, including polymorphic cases.
-- Note that RETURN is optional with OUT params; we try both ways.
--
-- wrong way to do it:
......@@ -1582,7 +1583,6 @@ select * from f1(42);
create or replace function f1(inout i int) as $$
begin
i := i+1;
return;
end$$ language plpgsql;
select f1(42);
......@@ -1608,7 +1608,6 @@ begin
j := i;
j := j+1;
k := 'foo';
return;
end$$ language plpgsql;
select f1(42);
......@@ -1624,7 +1623,6 @@ begin
j := j+1;
k := 'foot';
return next;
return;
end$$ language plpgsql;
select * from f1(42);
......@@ -2001,3 +1999,22 @@ create function void_return_expr() returns void as $$
begin
return 5;
end;$$ language plpgsql;
-- VOID functions are allowed to omit RETURN
create function void_return_expr() returns void as $$
begin
perform 2+2;
end;$$ language plpgsql;
select void_return_expr();
-- but ordinary functions are not
create function missing_return_expr() returns int as $$
begin
perform 2+2;
end;$$ language plpgsql;
select missing_return_expr();
drop function void_return_expr();
drop function missing_return_expr();
Markdown is supported
0% or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment