Skip to content
Projects
Groups
Snippets
Help
Loading...
Help
Support
Keyboard shortcuts
?
Submit feedback
Contribute to GitLab
Sign in
Toggle navigation
P
Postgres FD Implementation
Project overview
Project overview
Details
Activity
Releases
Repository
Repository
Files
Commits
Branches
Tags
Contributors
Graph
Compare
Issues
0
Issues
0
List
Boards
Labels
Milestones
Merge Requests
0
Merge Requests
0
CI / CD
CI / CD
Pipelines
Jobs
Schedules
Analytics
Analytics
CI / CD
Repository
Value Stream
Wiki
Wiki
Snippets
Snippets
Members
Members
Collapse sidebar
Close sidebar
Activity
Graph
Create a new issue
Jobs
Commits
Issue Boards
Open sidebar
Abuhujair Javed
Postgres FD Implementation
Commits
fd97cf4d
Commit
fd97cf4d
authored
Apr 05, 2005
by
Tom Lane
Browse files
Options
Browse Files
Download
Email Patches
Plain Diff
plpgsql does OUT parameters, as per my proposal a few weeks ago.
parent
2af664e7
Changes
10
Expand all
Hide whitespace changes
Inline
Side-by-side
Showing
10 changed files
with
958 additions
and
359 deletions
+958
-359
doc/src/sgml/plpgsql.sgml
doc/src/sgml/plpgsql.sgml
+119
-21
src/backend/utils/fmgr/funcapi.c
src/backend/utils/fmgr/funcapi.c
+103
-1
src/include/funcapi.h
src/include/funcapi.h
+5
-1
src/pl/plpgsql/src/gram.y
src/pl/plpgsql/src/gram.y
+39
-21
src/pl/plpgsql/src/pl_comp.c
src/pl/plpgsql/src/pl_comp.c
+321
-137
src/pl/plpgsql/src/pl_exec.c
src/pl/plpgsql/src/pl_exec.c
+154
-160
src/pl/plpgsql/src/pl_funcs.c
src/pl/plpgsql/src/pl_funcs.c
+10
-12
src/pl/plpgsql/src/plpgsql.h
src/pl/plpgsql/src/plpgsql.h
+4
-5
src/test/regress/expected/plpgsql.out
src/test/regress/expected/plpgsql.out
+119
-0
src/test/regress/sql/plpgsql.sql
src/test/regress/sql/plpgsql.sql
+84
-1
No files found.
doc/src/sgml/plpgsql.sgml
View file @
fd97cf4d
<!--
$PostgreSQL: pgsql/doc/src/sgml/plpgsql.sgml,v 1.6
2 2005/03/13 09:36:30 neilc
Exp $
$PostgreSQL: pgsql/doc/src/sgml/plpgsql.sgml,v 1.6
3 2005/04/05 06:22:14 tgl
Exp $
-->
<chapter id="plpgsql">
...
...
@@ -83,7 +83,7 @@ $PostgreSQL: pgsql/doc/src/sgml/plpgsql.sgml,v 1.62 2005/03/13 09:36:30 neilc Ex
that contains many statements for which execution plans might be
required will only prepare and save those plans that are really
used during the lifetime of the database connection. This can
substantially reduce the total amount of time required to parse
,
substantially reduce the total amount of time required to parse
and generate execution plans for the statements in a
<application>PL/pgSQL</> function. A disadvantage is that errors
in a specific expression or command may not be detected until that
...
...
@@ -215,6 +215,7 @@ $$ LANGUAGE plpgsql;
<type>void</> if it has no useful return value.
</para>
<note>
<para>
<application>PL/pgSQL</> does not currently have full support for
domain types: it treats a domain the same as the underlying scalar
...
...
@@ -223,6 +224,20 @@ $$ LANGUAGE plpgsql;
it is a hazard if you declare a <application>PL/pgSQL</> function
as returning a domain type.
</para>
</note>
<para>
<application>PL/pgSQL</> functions can also be declared with output
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.
</para>
<para>
Specific examples appear in
<xref linkend="plpgsql-declaration-aliases"> and
<xref linkend="plpgsql-statements-returning">.
</para>
</sect2>
</sect1>
...
...
@@ -631,12 +646,12 @@ DECLARE
v_string ALIAS FOR $1;
index ALIAS FOR $2;
BEGIN
-- some computations here
-- some computations
using v_string and index
here
END;
$$ LANGUAGE plpgsql;
CREATE FUNCTION concat_selected_fields(in_t tablename) RETURNS text AS $$
CREATE FUNCTION concat_selected_fields(in_t
some
tablename) RETURNS text AS $$
BEGIN
RETURN in_t.f1 || in_t.f3 || in_t.f5 || in_t.f7;
END;
...
...
@@ -644,6 +659,49 @@ $$ LANGUAGE plpgsql;
</programlisting>
</para>
<para>
When a <application>PL/pgSQL</application> function is declared
with output parameters, the output parameters are given
<literal>$<replaceable>n</replaceable></literal> names and optional
aliases in just the same way as the normal input parameters. An
output parameter is effectively a variable that starts out NULL;
it should be assigned to during the execution of the function.
The final value of the parameter is what is returned. For instance,
the sales-tax example could also be done this way:
<programlisting>
CREATE FUNCTION sales_tax(subtotal real, OUT tax real) AS $$
BEGIN
tax := subtotal * 0.06;
RETURN;
END;
$$ LANGUAGE plpgsql;
</programlisting>
Notice that we omitted <literal>RETURNS real</> — we could have
included it, but it would be redundant.
</para>
<para>
Output parameters are most useful when returning multiple values.
A trivial example is:
<programlisting>
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>
As discussed in <xref linkend="xfunc-output-parameters">, this
effectively creates an anonymous record type for the function's
results. If a <literal>RETURNS</> clause is given, it must say
<literal>RETURNS record</>.
</para>
<para>
When the return type of a <application>PL/pgSQL</application>
function is declared as a polymorphic type (<type>anyelement</type>
...
...
@@ -658,6 +716,7 @@ $$ LANGUAGE plpgsql;
though that is not required. <literal>$0</literal> can also be
given an alias. For example, this function works on any data type
that has a <literal>+</> operator:
<programlisting>
CREATE FUNCTION add_three_values(v1 anyelement, v2 anyelement, v3 anyelement)
RETURNS anyelement AS $$
...
...
@@ -668,6 +727,24 @@ BEGIN
RETURN result;
END;
$$ LANGUAGE plpgsql;
</programlisting>
</para>
<para>
The same effect can be had by declaring one or more output parameters as
<type>anyelement</type> or <type>anyarray</type>. In this case the
special <literal>$0</literal> parameter is not used; the output
parameters themselves serve the same purpose. For example:
<programlisting>
CREATE FUNCTION add_three_values(v1 anyelement, v2 anyelement, v3 anyelement,
OUT sum anyelement)
AS $$
BEGIN
sum := v1 + v2 + v3;
RETURN;
END;
$$ LANGUAGE plpgsql;
</programlisting>
</para>
</sect2>
...
...
@@ -756,18 +833,21 @@ user_id users.user_id%TYPE;
</para>
<para>
Here is an example of using composite types:
Here is an example of using composite types. <structname>table1</>
and <structname>table2</> are existing tables having at least the
mentioned fields:
<programlisting>
CREATE FUNCTION merge_fields(t_row table
name
) RETURNS text AS $$
CREATE FUNCTION merge_fields(t_row table
1
) RETURNS text AS $$
DECLARE
t2_row table2
name
%ROWTYPE;
t2_row table2%ROWTYPE;
BEGIN
SELECT * INTO t2_row FROM table2
name
WHERE ... ;
SELECT * INTO t2_row FROM table2 WHERE ... ;
RETURN t_row.f1 || t2_row.f3 || t_row.f5 || t2_row.f7;
END;
$$ LANGUAGE plpgsql;
SELECT merge_fields(t.*) FROM table
name
t WHERE ... ;
SELECT merge_fields(t.*) FROM table
1
t WHERE ... ;
</programlisting>
</para>
</sect2>
...
...
@@ -1411,6 +1491,12 @@ RETURN <replaceable>expression</replaceable>;
as the <replaceable>expression</replaceable>.
</para>
<para>
If you declared the function with output parameters, write just
<command>RETURN</command> with no expression. The current values
of the output parameter variables will be returned.
</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
...
...
@@ -1441,8 +1527,30 @@ RETURN NEXT <replaceable>expression</replaceable>;
commands, and then a final <command>RETURN</command> command
with no argument is used to indicate that the function has
finished executing. <command>RETURN NEXT</command> can be used
with both scalar and composite data types; in the latter case, an
entire <quote>table</quote> of results will be returned.
with both scalar and composite data types; with a composite result
type, an entire <quote>table</quote> of results will be returned.
</para>
<para>
<command>RETURN NEXT</command> does not actually return from the
function — it simply saves away the value of the expression.
Execution then continues with the next statement in
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.
</para>
<para>
If you declared the function with output parameters, write just
<command>RETURN NEXT</command> with no expression. The current values
of the output parameter variable(s) will be saved for eventual return.
Note that you must declare the function as returning
<literal>SETOF record</literal> when there are
multiple output parameters, or
<literal>SETOF <replaceable>sometype</></literal> when there is
just one output parameter of type <replaceable>sometype</>, in
order to create a set-returning function with output parameters.
</para>
<para>
...
...
@@ -1457,16 +1565,6 @@ SELECT * FROM some_func();
<literal>FROM</literal> clause.
</para>
<para>
<command>RETURN NEXT</command> does not actually return from the
function; it simply saves away the value of the expression.
Execution then continues with the next statement in
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.
</para>
<note>
<para>
The current implementation of <command>RETURN NEXT</command>
...
...
src/backend/utils/fmgr/funcapi.c
View file @
fd97cf4d
...
...
@@ -7,7 +7,7 @@
* Copyright (c) 2002-2005, PostgreSQL Global Development Group
*
* IDENTIFICATION
* $PostgreSQL: pgsql/src/backend/utils/fmgr/funcapi.c,v 1.
19 2005/03/31 22:46:16
tgl Exp $
* $PostgreSQL: pgsql/src/backend/utils/fmgr/funcapi.c,v 1.
20 2005/04/05 06:22:14
tgl Exp $
*
*-------------------------------------------------------------------------
*/
...
...
@@ -483,6 +483,108 @@ resolve_polymorphic_tupdesc(TupleDesc tupdesc, oidvector *declared_args,
return
true
;
}
/*
* Given the declared argument types and modes for a function,
* replace any polymorphic types (ANYELEMENT/ANYARRAY) with correct data
* types deduced from the input arguments. Returns TRUE if able to deduce
* all types, FALSE if not. This is the same logic as
* resolve_polymorphic_tupdesc, but with a different argument representation.
*
* argmodes may be NULL, in which case all arguments are assumed to be IN mode.
*/
bool
resolve_polymorphic_argtypes
(
int
numargs
,
Oid
*
argtypes
,
char
*
argmodes
,
Node
*
call_expr
)
{
bool
have_anyelement_result
=
false
;
bool
have_anyarray_result
=
false
;
Oid
anyelement_type
=
InvalidOid
;
Oid
anyarray_type
=
InvalidOid
;
int
inargno
;
int
i
;
/* First pass: resolve polymorphic inputs, check for outputs */
inargno
=
0
;
for
(
i
=
0
;
i
<
numargs
;
i
++
)
{
char
argmode
=
argmodes
?
argmodes
[
i
]
:
PROARGMODE_IN
;
switch
(
argtypes
[
i
])
{
case
ANYELEMENTOID
:
if
(
argmode
==
PROARGMODE_OUT
)
have_anyelement_result
=
true
;
else
{
if
(
!
OidIsValid
(
anyelement_type
))
{
anyelement_type
=
get_call_expr_argtype
(
call_expr
,
inargno
);
if
(
!
OidIsValid
(
anyelement_type
))
return
false
;
}
argtypes
[
i
]
=
anyelement_type
;
}
break
;
case
ANYARRAYOID
:
if
(
argmode
==
PROARGMODE_OUT
)
have_anyarray_result
=
true
;
else
{
if
(
!
OidIsValid
(
anyarray_type
))
{
anyarray_type
=
get_call_expr_argtype
(
call_expr
,
inargno
);
if
(
!
OidIsValid
(
anyarray_type
))
return
false
;
}
argtypes
[
i
]
=
anyarray_type
;
}
break
;
default:
break
;
}
if
(
argmode
!=
PROARGMODE_OUT
)
inargno
++
;
}
/* Done? */
if
(
!
have_anyelement_result
&&
!
have_anyarray_result
)
return
true
;
/* If no input polymorphics, parser messed up */
if
(
!
OidIsValid
(
anyelement_type
)
&&
!
OidIsValid
(
anyarray_type
))
return
false
;
/* If needed, deduce one polymorphic type from the other */
if
(
have_anyelement_result
&&
!
OidIsValid
(
anyelement_type
))
anyelement_type
=
resolve_generic_type
(
ANYELEMENTOID
,
anyarray_type
,
ANYARRAYOID
);
if
(
have_anyarray_result
&&
!
OidIsValid
(
anyarray_type
))
anyarray_type
=
resolve_generic_type
(
ANYARRAYOID
,
anyelement_type
,
ANYELEMENTOID
);
/* And finally replace the output column types as needed */
for
(
i
=
0
;
i
<
numargs
;
i
++
)
{
switch
(
argtypes
[
i
])
{
case
ANYELEMENTOID
:
argtypes
[
i
]
=
anyelement_type
;
break
;
case
ANYARRAYOID
:
argtypes
[
i
]
=
anyarray_type
;
break
;
default:
break
;
}
}
return
true
;
}
/*
* get_type_func_class
* Given the type OID, obtain its TYPEFUNC classification.
...
...
src/include/funcapi.h
View file @
fd97cf4d
...
...
@@ -9,7 +9,7 @@
*
* Copyright (c) 2002-2005, PostgreSQL Global Development Group
*
* $PostgreSQL: pgsql/src/include/funcapi.h,v 1.1
6 2005/03/31 22:46:24
tgl Exp $
* $PostgreSQL: pgsql/src/include/funcapi.h,v 1.1
7 2005/04/05 06:22:15
tgl Exp $
*
*-------------------------------------------------------------------------
*/
...
...
@@ -167,6 +167,10 @@ extern TypeFuncClass get_func_result_type(Oid functionId,
Oid
*
resultTypeId
,
TupleDesc
*
resultTupleDesc
);
extern
bool
resolve_polymorphic_argtypes
(
int
numargs
,
Oid
*
argtypes
,
char
*
argmodes
,
Node
*
call_expr
);
extern
TupleDesc
build_function_result_tupdesc_d
(
Datum
proallargtypes
,
Datum
proargmodes
,
Datum
proargnames
);
...
...
src/pl/plpgsql/src/gram.y
View file @
fd97cf4d
...
...
@@ -4,7 +4,7 @@
* procedural language
*
* IDENTIFICATION
* $PostgreSQL: pgsql/src/pl/plpgsql/src/gram.y,v 1.6
6 2005/02/22 07:18:24 neilc
Exp $
* $PostgreSQL: pgsql/src/pl/plpgsql/src/gram.y,v 1.6
7 2005/04/05 06:22:16 tgl
Exp $
*
* This software is copyrighted by Jan Wieck - Hamburg.
*
...
...
@@ -1052,28 +1052,41 @@ stmt_return : K_RETURN lno
PLpgSQL_stmt_return *new;
new = palloc0(sizeof(PLpgSQL_stmt_return));
new->cmd_type = PLPGSQL_STMT_RETURN;
new->lineno = $2;
new->expr = NULL;
new->retrecno = -1;
new->retrowno = -1;
new->retvarno = -1;
if (plpgsql_curr_compile->fn_retset)
{
if (yylex() != ';')
yyerror("RETURN cannot have a parameter in function returning set; use RETURN NEXT");
}
else if (plpgsql_curr_compile->out_param_varno >= 0)
{
if (yylex() != ';')
yyerror("RETURN cannot have a parameter in function with OUT parameters");
new->retvarno = plpgsql_curr_compile->out_param_varno;
}
else if (plpgsql_curr_compile->fn_rettype == VOIDOID)
{
if (yylex() != ';')
yyerror("function returning void cannot specify RETURN expression");
}
else if (plpgsql_curr_compile->fn_retistuple)
{
switch (yylex())
{
case K_NULL:
/* we allow this to support RETURN NULL in triggers */
break;
case T_ROW:
new->ret
row
no = yylval.row->rowno;
new->ret
var
no = yylval.row->rowno;
break;
case T_RECORD:
new->ret
rec
no = yylval.rec->recno;
new->ret
var
no = yylval.rec->recno;
break;
default:
...
...
@@ -1083,11 +1096,6 @@ stmt_return : K_RETURN lno
if (yylex() != ';')
yyerror("RETURN must specify a record or row variable in function returning tuple");
}
else if (plpgsql_curr_compile->fn_rettype == VOIDOID)
{
if (yylex() != ';')
yyerror("function returning void cannot specify RETURN expression");
}
else
{
/*
...
...
@@ -1098,9 +1106,6 @@ stmt_return : K_RETURN lno
new->expr = plpgsql_read_expression(';', ";");
}
new->cmd_type = PLPGSQL_STMT_RETURN;
new->lineno = $2;
$$ = (PLpgSQL_stmt *)new;
}
;
...
...
@@ -1115,18 +1120,31 @@ stmt_return_next: K_RETURN_NEXT lno
new = palloc0(sizeof(PLpgSQL_stmt_return_next));
new->cmd_type = PLPGSQL_STMT_RETURN_NEXT;
new->lineno = $2;
new->expr = NULL;
new->retvarno = -1;
if (plpgsql_curr_compile->
fn_retistuple
)
if (plpgsql_curr_compile->
out_param_varno >= 0
)
{
int tok = yylex();
if (yylex() != ';')
yyerror("RETURN NEXT cannot have a parameter in function with OUT parameters");
new->retvarno = plpgsql_curr_compile->out_param_varno;
}
else if (plpgsql_curr_compile->fn_retistuple)
{
switch (yylex())
{
case T_ROW:
new->retvarno = yylval.row->rowno;
break;
if (tok == T_RECORD)
new->rec = yylval.rec;
else if (tok == T_ROW)
new->row = yylval.row;
else
yyerror("RETURN NEXT must specify a record or row variable in function returning tuple");
case T_RECORD:
new->retvarno = yylval.rec->recno;
break;
default:
yyerror("RETURN NEXT must specify a record or row variable in function returning tuple");
break;
}
if (yylex() != ';')
yyerror("RETURN NEXT must specify a record or row variable in function returning tuple");
}
...
...
src/pl/plpgsql/src/pl_comp.c
View file @
fd97cf4d
This diff is collapsed.
Click to expand it.
src/pl/plpgsql/src/pl_exec.c
View file @
fd97cf4d
This diff is collapsed.
Click to expand it.
src/pl/plpgsql/src/pl_funcs.c
View file @
fd97cf4d
...
...
@@ -3,7 +3,7 @@
* procedural language
*
* IDENTIFICATION
* $PostgreSQL: pgsql/src/pl/plpgsql/src/pl_funcs.c,v 1.
39 2005/02/22 07:18:24 neilc
Exp $
* $PostgreSQL: pgsql/src/pl/plpgsql/src/pl_funcs.c,v 1.
40 2005/04/05 06:22:16 tgl
Exp $
*
* This software is copyrighted by Jan Wieck - Hamburg.
*
...
...
@@ -857,14 +857,12 @@ dump_return(PLpgSQL_stmt_return *stmt)
{
dump_ind
();
printf
(
"RETURN "
);
if
(
stmt
->
retrecno
>=
0
)
printf
(
"record %d"
,
stmt
->
retrecno
);
else
if
(
stmt
->
retrowno
>=
0
)
printf
(
"row %d"
,
stmt
->
retrowno
);
else
if
(
stmt
->
expr
==
NULL
)
printf
(
"NULL"
);
else
if
(
stmt
->
retvarno
>=
0
)
printf
(
"variable %d"
,
stmt
->
retvarno
);
else
if
(
stmt
->
expr
!=
NULL
)
dump_expr
(
stmt
->
expr
);
else
printf
(
"NULL"
);
printf
(
"
\n
"
);
}
...
...
@@ -873,12 +871,12 @@ dump_return_next(PLpgSQL_stmt_return_next *stmt)
{
dump_ind
();
printf
(
"RETURN NEXT "
);
if
(
stmt
->
rec
!=
NULL
)
printf
(
"target = %d %s
\n
"
,
stmt
->
rec
->
recno
,
stmt
->
rec
->
refname
);
else
if
(
stmt
->
row
!=
NULL
)
printf
(
"target = %d %s
\n
"
,
stmt
->
row
->
rowno
,
stmt
->
row
->
refname
);
if
(
stmt
->
retvarno
>=
0
)
printf
(
"variable %d"
,
stmt
->
retvarno
);
else
if
(
stmt
->
expr
!=
NULL
)
dump_expr
(
stmt
->
expr
);
else
printf
(
"NULL"
);
printf
(
"
\n
"
);
}
...
...
src/pl/plpgsql/src/plpgsql.h
View file @
fd97cf4d
...
...
@@ -3,7 +3,7 @@
* procedural language
*
* IDENTIFICATION
* $PostgreSQL: pgsql/src/pl/plpgsql/src/plpgsql.h,v 1.5
7 2005/02/22 07:18:24 neilc
Exp $
* $PostgreSQL: pgsql/src/pl/plpgsql/src/plpgsql.h,v 1.5
8 2005/04/05 06:22:16 tgl
Exp $
*
* This software is copyrighted by Jan Wieck - Hamburg.
*
...
...
@@ -491,17 +491,15 @@ typedef struct
int
cmd_type
;
int
lineno
;
PLpgSQL_expr
*
expr
;
int
retrecno
;
int
retrowno
;
int
retvarno
;
}
PLpgSQL_stmt_return
;
typedef
struct
{
/* RETURN NEXT statement */
int
cmd_type
;
int
lineno
;
PLpgSQL_rec
*
rec
;
PLpgSQL_row
*
row
;
PLpgSQL_expr
*
expr
;
int
retvarno
;
}
PLpgSQL_stmt_return_next
;
typedef
struct
...
...
@@ -572,6 +570,7 @@ typedef struct PLpgSQL_function
int
fn_nargs
;
int
fn_argvarnos
[
FUNC_MAX_ARGS
];
int
out_param_varno
;
int
found_varno
;
int
new_varno
;
int
old_varno
;
...
...
src/test/regress/expected/plpgsql.out
View file @
fd97cf4d
...
...
@@ -1738,6 +1738,125 @@ SELECT * FROM test_ret_rec_dyn(5) AS (a int, b numeric, c text);
50 | 5 | xxx
(1 row)
--
-- Test handling of OUT parameters, including polymorphic cases
--
-- wrong way to do it:
create function f1(in i int, out j int) returns int as $$
begin
return i+1;
end$$ language plpgsql;
ERROR: RETURN cannot have a parameter in function with OUT parameters at or near "i" at character 74
LINE 3: return i+1;
^
create function f1(in i int, out j int) as $$
begin
j := i+1;
return;
end$$ language plpgsql;
select f1(42);
f1
----
43
(1 row)
select * from f1(42);
f1
----
43
(1 row)
create or replace function f1(inout i int) as $$
begin
i := i+1;
return;
end$$ language plpgsql;
select f1(42);
f1
----
43
(1 row)
select * from f1(42);
f1
----
43
(1 row)
drop function f1(int);
create function f1(in i int, out j int) returns setof int as $$
begin
j := i+1;
return next;
j := i+2;
return next;
return;
end$$ language plpgsql;
select * from f1(42);
f1
----
43
44
(2 rows)
drop function f1(int);
create function f1(in i int, out j int, out k text) as $$
begin
j := i;
j := j+1;
k := 'foo';
return;
end$$ language plpgsql;
select f1(42);
f1
----------
(43,foo)
(1 row)
select * from f1(42);
j | k
----+-----
43 | foo
(1 row)
drop function f1(int);
create function f1(in i int, out j int, out k text) returns setof record as $$
begin
j := i+1;
k := 'foo';
return next;
j := j+1;
k := 'foot';
return next;
return;
end$$ language plpgsql;
select * from f1(42);
j | k
----+------
43 | foo
44 | foot
(2 rows)
drop function f1(int);
create function dup(in i anyelement, out j anyelement, out k anyarray) as $$
begin
j := i;
k := array[j,j];
return;
end$$ language plpgsql;
select * from dup(42);
j | k
----+---------
42 | {42,42}
(1 row)
select * from dup('foo'::text);
j | k
-----+-----------
foo | {foo,foo}
(1 row)
drop function dup(anyelement);
--
-- test PERFORM
--
...
...
src/test/regress/sql/plpgsql.sql
View file @
fd97cf4d
...
...
@@ -1560,6 +1560,89 @@ END;' language 'plpgsql';
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
--
-- wrong way to do it:
create
function
f1
(
in
i
int
,
out
j
int
)
returns
int
as
$$
begin
return
i
+
1
;
end
$$
language
plpgsql
;
create
function
f1
(
in
i
int
,
out
j
int
)
as
$$
begin
j
:
=
i
+
1
;
return
;
end
$$
language
plpgsql
;
select
f1
(
42
);
select
*
from
f1
(
42
);
create
or
replace
function
f1
(
inout
i
int
)
as
$$
begin
i
:
=
i
+
1
;
return
;
end
$$
language
plpgsql
;
select
f1
(
42
);
select
*
from
f1
(
42
);
drop
function
f1
(
int
);
create
function
f1
(
in
i
int
,
out
j
int
)
returns
setof
int
as
$$
begin
j
:
=
i
+
1
;
return
next
;
j
:
=
i
+
2
;
return
next
;
return
;
end
$$
language
plpgsql
;
select
*
from
f1
(
42
);
drop
function
f1
(
int
);
create
function
f1
(
in
i
int
,
out
j
int
,
out
k
text
)
as
$$
begin
j
:
=
i
;
j
:
=
j
+
1
;
k
:
=
'foo'
;
return
;
end
$$
language
plpgsql
;
select
f1
(
42
);
select
*
from
f1
(
42
);
drop
function
f1
(
int
);
create
function
f1
(
in
i
int
,
out
j
int
,
out
k
text
)
returns
setof
record
as
$$
begin
j
:
=
i
+
1
;
k
:
=
'foo'
;
return
next
;
j
:
=
j
+
1
;
k
:
=
'foot'
;
return
next
;
return
;
end
$$
language
plpgsql
;
select
*
from
f1
(
42
);
drop
function
f1
(
int
);
create
function
dup
(
in
i
anyelement
,
out
j
anyelement
,
out
k
anyarray
)
as
$$
begin
j
:
=
i
;
k
:
=
array
[
j
,
j
];
return
;
end
$$
language
plpgsql
;
select
*
from
dup
(
42
);
select
*
from
dup
(
'foo'
::
text
);
drop
function
dup
(
anyelement
);
--
-- test PERFORM
--
...
...
@@ -1917,4 +2000,4 @@ end;$$ language plpgsql;
create
function
void_return_expr
()
returns
void
as
$$
begin
return
5
;
end
;
$$
language
plpgsql
;
\ No newline at end of file
end
;
$$
language
plpgsql
;
Write
Preview
Markdown
is supported
0%
Try again
or
attach a new file
Attach a file
Cancel
You are about to add
0
people
to the discussion. Proceed with caution.
Finish editing this message first!
Cancel
Please
register
or
sign in
to comment