Allow SQL-language functions to return the output of an INSERT/UPDATE/DELETE

RETURNING clause, not just a SELECT as formerly.

A side effect of this patch is that when a set-returning SQL function is used
in a FROM clause, performance is improved because the output is collected into
a tuplestore within the function, rather than using the less efficient
value-per-call mechanism.
This commit is contained in:
Tom Lane 2008-10-31 19:37:56 +00:00
parent cd97f98844
commit 9b46abb7c4
11 changed files with 833 additions and 312 deletions

View File

@ -1,4 +1,4 @@
<!-- $PostgreSQL: pgsql/doc/src/sgml/xfunc.sgml,v 1.132 2008/07/18 03:32:52 tgl Exp $ -->
<!-- $PostgreSQL: pgsql/doc/src/sgml/xfunc.sgml,v 1.133 2008/10/31 19:37:56 tgl Exp $ -->
<sect1 id="xfunc">
<title>User-Defined Functions</title>
@ -106,7 +106,9 @@
The body of an SQL function must be a list of SQL
statements separated by semicolons. A semicolon after the last
statement is optional. Unless the function is declared to return
<type>void</>, the last statement must be a <command>SELECT</>.
<type>void</>, the last statement must be a <command>SELECT</>,
or an <command>INSERT</>, <command>UPDATE</>, or <command>DELETE</>
that has a <literal>RETURNING</> clause.
</para>
<para>
@ -119,11 +121,11 @@
<command>BEGIN</>, <command>COMMIT</>, <command>ROLLBACK</>, or
<command>SAVEPOINT</> commands into a <acronym>SQL</acronym> function.)
However, the final command
must be a <command>SELECT</command> that returns whatever is
must be a <command>SELECT</command> or have a <literal>RETURNING</>
clause 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 <type>void</>.
In that case, the function body must not end with a <command>SELECT</command>.
For example, this function removes rows with negative salaries from
the <literal>emp</> table:
@ -257,6 +259,16 @@ $$ LANGUAGE SQL;
</programlisting>
which adjusts the balance and returns the new balance.
The same thing could be done in one command using <literal>RETURNING</>:
<programlisting>
CREATE FUNCTION tf1 (integer, numeric) RETURNS numeric AS $$
UPDATE bank
SET balance = balance - $2
WHERE accountno = $1
RETURNING balance;
$$ LANGUAGE SQL;
</programlisting>
</para>
</sect2>
@ -422,7 +434,7 @@ SELECT (new_emp()).name;
<screen>
SELECT new_emp().name;
ERROR: syntax error at or near "." at character 17
ERROR: syntax error at or near "."
LINE 1: SELECT new_emp().name;
^
</screen>
@ -705,7 +717,7 @@ SELECT *, upper(fooname) FROM getfoo(1) AS t1;
<para>
When an SQL function is declared as returning <literal>SETOF
<replaceable>sometype</></literal>, the function's final
<command>SELECT</> query is executed to completion, and each row it
query is executed to completion, and each row it
outputs is returned as an element of the result set.
</para>
@ -798,6 +810,18 @@ SELECT name, listchildren(name) FROM nodes;
This happens because <function>listchildren</function> returns an empty set
for those arguments, so no result rows are generated.
</para>
<note>
<para>
If a function's last command is <command>INSERT</>, <command>UPDATE</>,
or <command>DELETE</> with <literal>RETURNING</>, that command will
always be executed to completion, even if the function is not declared
with <literal>SETOF</> or the calling query does not fetch all the
result rows. Any extra rows produced by the <literal>RETURNING</>
clause are silently dropped, but the commanded table modifications
still happen (and are all completed before returning from the function).
</para>
</note>
</sect2>
<sect2 id="xfunc-sql-functions-returning-table">
@ -1459,16 +1483,13 @@ PG_MODULE_MAGIC;
<para>
By-value types can only be 1, 2, or 4 bytes in length
(also 8 bytes, if <literal>sizeof(Datum)</literal> is 8 on your machine).
You should be careful
to define your types such that they will be the same
size (in bytes) on all architectures. For example, the
<literal>long</literal> type is dangerous because it
is 4 bytes on some machines and 8 bytes on others, whereas
<type>int</type> type is 4 bytes on most
Unix machines. A reasonable implementation of
the <type>int4</type> type on Unix
machines might be:
You should be careful to define your types such that they will be the
same size (in bytes) on all architectures. For example, the
<literal>long</literal> type is dangerous because it is 4 bytes on some
machines and 8 bytes on others, whereas <type>int</type> type is 4 bytes
on most Unix machines. A reasonable implementation of the
<type>int4</type> type on Unix machines might be:
<programlisting>
/* 4-byte integer, passed by value */
typedef int int4;
@ -1479,7 +1500,7 @@ typedef int int4;
On the other hand, fixed-length types of any size can
be passed by-reference. For example, here is a sample
implementation of a <productname>PostgreSQL</productname> type:
<programlisting>
/* 16-byte structure, passed by reference */
typedef struct
@ -1502,7 +1523,7 @@ typedef struct
Finally, all variable-length types must also be passed
by reference. All variable-length types must begin
with a length field of exactly 4 bytes, and all data to
be stored within that type must be located in the memory
be stored within that type must be located in the memory
immediately following that length field. The
length field contains the total length of the structure,
that is, it includes the size of the length field
@ -1540,8 +1561,8 @@ typedef struct {
</para>
<para>
When manipulating
variable-length types, we must be careful to allocate
When manipulating
variable-length types, we must be careful to allocate
the correct amount of memory and set the length field correctly.
For example, if we wanted to store 40 bytes in a <structname>text</>
structure, we might use a code fragment like this:
@ -1772,7 +1793,7 @@ memcpy(destination-&gt;data, buffer, 40);
#include &lt;string.h&gt;
/* by value */
int
add_one(int arg)
{
@ -1787,7 +1808,7 @@ add_one_float8(float8 *arg)
float8 *result = (float8 *) palloc(sizeof(float8));
*result = *arg + 1.0;
return result;
}
@ -1798,7 +1819,7 @@ makepoint(Point *pointx, Point *pointy)
new_point-&gt;x = pointx-&gt;x;
new_point-&gt;y = pointy-&gt;y;
return new_point;
}
@ -1841,7 +1862,7 @@ concat_text(text *arg1, text *arg2)
<filename>funcs.c</filename> and compiled into a shared object,
we could define the functions to <productname>PostgreSQL</productname>
with commands like this:
<programlisting>
CREATE FUNCTION add_one(integer) RETURNS integer
AS '<replaceable>DIRECTORY</replaceable>/funcs', 'add_one'
@ -1855,7 +1876,7 @@ CREATE FUNCTION add_one(double precision) RETURNS double precision
CREATE FUNCTION makepoint(point, point) RETURNS point
AS '<replaceable>DIRECTORY</replaceable>/funcs', 'makepoint'
LANGUAGE C STRICT;
CREATE FUNCTION copytext(text) RETURNS text
AS '<replaceable>DIRECTORY</replaceable>/funcs', 'copytext'
LANGUAGE C STRICT;
@ -1947,7 +1968,7 @@ PG_FUNCTION_INFO_V1(funcname);
/* by value */
PG_FUNCTION_INFO_V1(add_one);
Datum
add_one(PG_FUNCTION_ARGS)
{
@ -1981,7 +2002,7 @@ makepoint(PG_FUNCTION_ARGS)
new_point-&gt;x = pointx-&gt;x;
new_point-&gt;y = pointy-&gt;y;
PG_RETURN_POINT_P(new_point);
}
@ -2447,7 +2468,7 @@ include $(PGXS)
in the <literal>results/</literal> directory), and copying them to
<literal>expected/</literal> if they match what you want from the test.
</para>
</tip>
</sect2>
@ -2476,7 +2497,7 @@ SELECT name, c_overpaid(emp, 1500) AS overpaid
Using call conventions version 0, we can define
<function>c_overpaid</> as:
<programlisting>
#include "postgres.h"
#include "executor/executor.h" /* for GetAttributeByName() */
@ -2522,11 +2543,11 @@ c_overpaid(PG_FUNCTION_ARGS)
</para>
<para>
<function>GetAttributeByName</function> is the
<function>GetAttributeByName</function> is the
<productname>PostgreSQL</productname> system function that
returns attributes out of the specified row. It has
three arguments: the argument of type <type>HeapTupleHeader</type> passed
into
into
the function, the name of the desired attribute, and a
return parameter that tells whether the attribute
is null. <function>GetAttributeByName</function> returns a <type>Datum</type>
@ -2733,7 +2754,7 @@ typedef struct
{
/*
* Number of times we've been called before
*
*
* call_cntr is initialized to 0 for you by SRF_FIRSTCALL_INIT(), and
* incremented for you every time SRF_RETURN_NEXT() is called.
*/
@ -2750,7 +2771,7 @@ typedef struct
/*
* OPTIONAL pointer to result slot
*
*
* This is obsolete and only present for backwards compatibility, viz,
* user-defined SRFs that use the deprecated TupleDescGetSlot().
*/
@ -2758,7 +2779,7 @@ typedef struct
/*
* OPTIONAL pointer to miscellaneous user-provided context information
*
*
* user_fctx is for use as a pointer to your own data to retain
* arbitrary context information between calls of your function.
*/
@ -2766,7 +2787,7 @@ typedef struct
/*
* OPTIONAL pointer to struct containing attribute type input metadata
*
*
* attinmeta is for use when returning tuples (i.e., composite data types)
* and is not used when returning base data types. It is only needed
* if you intend to use BuildTupleFromCStrings() to create the return
@ -2948,7 +2969,7 @@ retcomposite(PG_FUNCTION_ARGS)
call_cntr = funcctx-&gt;call_cntr;
max_calls = funcctx-&gt;max_calls;
attinmeta = funcctx-&gt;attinmeta;
if (call_cntr &lt; max_calls) /* do when there is more left to send */
{
char **values;
@ -3126,7 +3147,7 @@ CREATE FUNCTION make_array(anyelement) RETURNS anyarray
<para>
Add-ins can reserve LWLocks and an allocation of shared memory on server
startup. The add-in's shared library must be preloaded by specifying
it in
it in
<xref linkend="guc-shared-preload-libraries"><indexterm><primary>shared-preload-libraries</></>.
Shared memory is reserved by calling:
<programlisting>
@ -3139,11 +3160,11 @@ void RequestAddinShmemSpace(int size)
<programlisting>
void RequestAddinLWLocks(int n)
</programlisting>
from <function>_PG_init</>.
from <function>_PG_init</>.
</para>
<para>
To avoid possible race-conditions, each backend should use the LWLock
<function>AddinShmemInitLock</> when connecting to and initializing
<function>AddinShmemInitLock</> when connecting to and initializing
its allocation of shared memory, as shown here:
<programlisting>
static mystruct *ptr = NULL;

View File

@ -8,7 +8,7 @@
*
*
* IDENTIFICATION
* $PostgreSQL: pgsql/src/backend/executor/execQual.c,v 1.235 2008/10/29 00:00:38 tgl Exp $
* $PostgreSQL: pgsql/src/backend/executor/execQual.c,v 1.236 2008/10/31 19:37:56 tgl Exp $
*
*-------------------------------------------------------------------------
*/
@ -1334,7 +1334,8 @@ ExecMakeFunctionResult(FuncExprState *fcache,
{
List *arguments;
Datum result;
FunctionCallInfoData fcinfo;
FunctionCallInfoData fcinfo_data;
FunctionCallInfo fcinfo;
PgStat_FunctionCallUsage fcusage;
ReturnSetInfo rsinfo; /* for functions returning sets */
ExprDoneCond argDone;
@ -1384,6 +1385,20 @@ restart:
Assert(!fcache->setArgsValid);
}
/*
* For non-set-returning functions, we just use a local-variable
* FunctionCallInfoData. For set-returning functions we keep the callinfo
* record in fcache->setArgs so that it can survive across multiple
* value-per-call invocations. (The reason we don't just do the latter
* all the time is that plpgsql expects to be able to use simple expression
* trees re-entrantly. Which might not be a good idea, but the penalty
* for not doing so is high.)
*/
if (fcache->func.fn_retset)
fcinfo = &fcache->setArgs;
else
fcinfo = &fcinfo_data;
/*
* arguments is a list of expressions to evaluate before passing to the
* function manager. We skip the evaluation if it was already done in the
@ -1394,8 +1409,8 @@ restart:
if (!fcache->setArgsValid)
{
/* Need to prep callinfo structure */
InitFunctionCallInfoData(fcinfo, &(fcache->func), 0, NULL, NULL);
argDone = ExecEvalFuncArgs(&fcinfo, arguments, econtext);
InitFunctionCallInfoData(*fcinfo, &(fcache->func), 0, NULL, NULL);
argDone = ExecEvalFuncArgs(fcinfo, arguments, econtext);
if (argDone == ExprEndResult)
{
/* input is an empty set, so return an empty set. */
@ -1412,8 +1427,7 @@ restart:
}
else
{
/* Copy callinfo from previous evaluation */
memcpy(&fcinfo, &fcache->setArgs, sizeof(fcinfo));
/* Re-use callinfo from previous evaluation */
hasSetArg = fcache->setHasSetArg;
/* Reset flag (we may set it again below) */
fcache->setArgsValid = false;
@ -1424,12 +1438,12 @@ restart:
*/
if (fcache->func.fn_retset)
{
fcinfo.resultinfo = (Node *) &rsinfo;
fcinfo->resultinfo = (Node *) &rsinfo;
rsinfo.type = T_ReturnSetInfo;
rsinfo.econtext = econtext;
rsinfo.expectedDesc = fcache->funcResultDesc;
rsinfo.allowedModes = (int) (SFRM_ValuePerCall | SFRM_Materialize);
/* note we do not set SFRM_Materialize_Random */
/* note we do not set SFRM_Materialize_Random or _Preferred */
rsinfo.returnMode = SFRM_ValuePerCall;
/* isDone is filled below */
rsinfo.setResult = NULL;
@ -1468,9 +1482,9 @@ restart:
if (fcache->func.fn_strict)
{
for (i = 0; i < fcinfo.nargs; i++)
for (i = 0; i < fcinfo->nargs; i++)
{
if (fcinfo.argnull[i])
if (fcinfo->argnull[i])
{
callit = false;
break;
@ -1480,12 +1494,12 @@ restart:
if (callit)
{
pgstat_init_function_usage(&fcinfo, &fcusage);
pgstat_init_function_usage(fcinfo, &fcusage);
fcinfo.isnull = false;
fcinfo->isnull = false;
rsinfo.isDone = ExprSingleResult;
result = FunctionCallInvoke(&fcinfo);
*isNull = fcinfo.isnull;
result = FunctionCallInvoke(fcinfo);
*isNull = fcinfo->isnull;
*isDone = rsinfo.isDone;
pgstat_end_function_usage(&fcusage,
@ -1511,7 +1525,7 @@ restart:
if (fcache->func.fn_retset &&
*isDone == ExprMultipleResult)
{
memcpy(&fcache->setArgs, &fcinfo, sizeof(fcinfo));
Assert(fcinfo == &fcache->setArgs);
fcache->setHasSetArg = hasSetArg;
fcache->setArgsValid = true;
/* Register cleanup callback if we didn't already */
@ -1567,7 +1581,7 @@ restart:
break; /* input not a set, so done */
/* Re-eval args to get the next element of the input set */
argDone = ExecEvalFuncArgs(&fcinfo, arguments, econtext);
argDone = ExecEvalFuncArgs(fcinfo, arguments, econtext);
if (argDone != ExprMultipleResult)
{
@ -1605,9 +1619,9 @@ restart:
*/
if (fcache->func.fn_strict)
{
for (i = 0; i < fcinfo.nargs; i++)
for (i = 0; i < fcinfo->nargs; i++)
{
if (fcinfo.argnull[i])
if (fcinfo->argnull[i])
{
*isNull = true;
return (Datum) 0;
@ -1615,11 +1629,11 @@ restart:
}
}
pgstat_init_function_usage(&fcinfo, &fcusage);
pgstat_init_function_usage(fcinfo, &fcusage);
fcinfo.isnull = false;
result = FunctionCallInvoke(&fcinfo);
*isNull = fcinfo.isnull;
fcinfo->isnull = false;
result = FunctionCallInvoke(fcinfo);
*isNull = fcinfo->isnull;
pgstat_end_function_usage(&fcusage, true);
}
@ -1737,7 +1751,7 @@ ExecMakeTableFunctionResult(ExprState *funcexpr,
rsinfo.type = T_ReturnSetInfo;
rsinfo.econtext = econtext;
rsinfo.expectedDesc = expectedDesc;
rsinfo.allowedModes = (int) (SFRM_ValuePerCall | SFRM_Materialize);
rsinfo.allowedModes = (int) (SFRM_ValuePerCall | SFRM_Materialize | SFRM_Materialize_Preferred);
if (randomAccess)
rsinfo.allowedModes |= (int) SFRM_Materialize_Random;
rsinfo.returnMode = SFRM_ValuePerCall;

File diff suppressed because it is too large Load Diff

View File

@ -8,7 +8,7 @@
* Portions Copyright (c) 1994, Regents of the University of California
*
* IDENTIFICATION
* $PostgreSQL: pgsql/src/backend/tcop/dest.c,v 1.72 2008/01/01 19:45:52 momjian Exp $
* $PostgreSQL: pgsql/src/backend/tcop/dest.c,v 1.73 2008/10/31 19:37:56 tgl Exp $
*
*-------------------------------------------------------------------------
*/
@ -32,6 +32,7 @@
#include "access/xact.h"
#include "commands/copy.h"
#include "executor/executor.h"
#include "executor/functions.h"
#include "executor/tstoreReceiver.h"
#include "libpq/libpq.h"
#include "libpq/pqformat.h"
@ -132,6 +133,9 @@ CreateDestReceiver(CommandDest dest, Portal portal)
case DestCopyOut:
return CreateCopyDestReceiver();
case DestSQLFunction:
return CreateSQLFunctionDestReceiver();
}
/* should never get here */
@ -158,6 +162,7 @@ EndCommand(const char *commandTag, CommandDest dest)
case DestTuplestore:
case DestIntoRel:
case DestCopyOut:
case DestSQLFunction:
break;
}
}
@ -198,6 +203,7 @@ NullCommand(CommandDest dest)
case DestTuplestore:
case DestIntoRel:
case DestCopyOut:
case DestSQLFunction:
break;
}
}
@ -240,6 +246,7 @@ ReadyForQuery(CommandDest dest)
case DestTuplestore:
case DestIntoRel:
case DestCopyOut:
case DestSQLFunction:
break;
}
}

View File

@ -1,4 +1,4 @@
$PostgreSQL: pgsql/src/backend/utils/fmgr/README,v 1.15 2008/10/29 00:00:38 tgl Exp $
$PostgreSQL: pgsql/src/backend/utils/fmgr/README,v 1.16 2008/10/31 19:37:56 tgl Exp $
Function Manager
================
@ -434,7 +434,9 @@ and returns null. isDone is not used and should be left at ExprSingleResult.
The Tuplestore must be created with randomAccess = true if
SFRM_Materialize_Random is set in allowedModes, but it can (and preferably
should) be created with randomAccess = false if not.
should) be created with randomAccess = false if not. Callers that can support
both ValuePerCall and Materialize mode will set SFRM_Materialize_Preferred,
or not, depending on which mode they prefer.
If available, the expected tuple descriptor is passed in ReturnSetInfo;
in other contexts the expectedDesc field will be NULL. The function need

View File

@ -7,7 +7,7 @@
* Portions Copyright (c) 1996-2008, PostgreSQL Global Development Group
* Portions Copyright (c) 1994, Regents of the University of California
*
* $PostgreSQL: pgsql/src/include/executor/functions.h,v 1.31 2008/03/18 22:04:14 tgl Exp $
* $PostgreSQL: pgsql/src/include/executor/functions.h,v 1.32 2008/10/31 19:37:56 tgl Exp $
*
*-------------------------------------------------------------------------
*/
@ -15,6 +15,7 @@
#define FUNCTIONS_H
#include "nodes/execnodes.h"
#include "tcop/dest.h"
extern Datum fmgr_sql(PG_FUNCTION_ARGS);
@ -24,4 +25,6 @@ extern bool check_sql_fn_retval(Oid func_id, Oid rettype,
bool insertRelabels,
JunkFilter **junkFilter);
extern DestReceiver *CreateSQLFunctionDestReceiver(void);
#endif /* FUNCTIONS_H */

View File

@ -7,7 +7,7 @@
* Portions Copyright (c) 1996-2008, PostgreSQL Global Development Group
* Portions Copyright (c) 1994, Regents of the University of California
*
* $PostgreSQL: pgsql/src/include/nodes/execnodes.h,v 1.193 2008/10/29 00:00:39 tgl Exp $
* $PostgreSQL: pgsql/src/include/nodes/execnodes.h,v 1.194 2008/10/31 19:37:56 tgl Exp $
*
*-------------------------------------------------------------------------
*/
@ -151,13 +151,15 @@ typedef enum
/*
* Return modes for functions returning sets. Note values must be chosen
* as separate bits so that a bitmask can be formed to indicate supported
* modes.
* modes. SFRM_Materialize_Random and SFRM_Materialize_Preferred are
* auxiliary flags about SFRM_Materialize mode, rather than separate modes.
*/
typedef enum
{
SFRM_ValuePerCall = 0x01, /* one value returned per call */
SFRM_Materialize = 0x02, /* result set instantiated in Tuplestore */
SFRM_Materialize_Random = 0x04 /* Tuplestore needs randomAccess */
SFRM_Materialize_Random = 0x04, /* Tuplestore needs randomAccess */
SFRM_Materialize_Preferred = 0x08 /* caller prefers Tuplestore */
} SetFunctionReturnMode;
/*

View File

@ -54,7 +54,7 @@
* Portions Copyright (c) 1996-2008, PostgreSQL Global Development Group
* Portions Copyright (c) 1994, Regents of the University of California
*
* $PostgreSQL: pgsql/src/include/tcop/dest.h,v 1.54 2008/01/01 19:45:59 momjian Exp $
* $PostgreSQL: pgsql/src/include/tcop/dest.h,v 1.55 2008/10/31 19:37:56 tgl Exp $
*
*-------------------------------------------------------------------------
*/
@ -86,7 +86,8 @@ typedef enum
DestSPI, /* results sent to SPI manager */
DestTuplestore, /* results sent to Tuplestore */
DestIntoRel, /* results sent to relation (SELECT INTO) */
DestCopyOut /* results sent to COPY TO code */
DestCopyOut, /* results sent to COPY TO code */
DestSQLFunction /* results sent to SQL-language func mgr */
} CommandDest;
/* ----------------

View File

@ -567,3 +567,179 @@ SELECT * FROM foo(3);
(9 rows)
DROP FUNCTION foo(int);
--
-- some tests on SQL functions with RETURNING
--
create temp table tt(f1 serial, data text);
NOTICE: CREATE TABLE will create implicit sequence "tt_f1_seq" for serial column "tt.f1"
create function insert_tt(text) returns int as
$$ insert into tt(data) values($1) returning f1 $$
language sql;
select insert_tt('foo');
insert_tt
-----------
1
(1 row)
select insert_tt('bar');
insert_tt
-----------
2
(1 row)
select * from tt;
f1 | data
----+------
1 | foo
2 | bar
(2 rows)
-- insert will execute to completion even if function needs just 1 row
create or replace function insert_tt(text) returns int as
$$ insert into tt(data) values($1),($1||$1) returning f1 $$
language sql;
select insert_tt('fool');
insert_tt
-----------
3
(1 row)
select * from tt;
f1 | data
----+----------
1 | foo
2 | bar
3 | fool
4 | foolfool
(4 rows)
-- setof does what's expected
create or replace function insert_tt2(text,text) returns setof int as
$$ insert into tt(data) values($1),($2) returning f1 $$
language sql;
select insert_tt2('foolish','barrish');
insert_tt2
------------
5
6
(2 rows)
select * from insert_tt2('baz','quux');
insert_tt2
------------
7
8
(2 rows)
select * from tt;
f1 | data
----+----------
1 | foo
2 | bar
3 | fool
4 | foolfool
5 | foolish
6 | barrish
7 | baz
8 | quux
(8 rows)
-- limit doesn't prevent execution to completion
select insert_tt2('foolish','barrish') limit 1;
insert_tt2
------------
9
(1 row)
select * from tt;
f1 | data
----+----------
1 | foo
2 | bar
3 | fool
4 | foolfool
5 | foolish
6 | barrish
7 | baz
8 | quux
9 | foolish
10 | barrish
(10 rows)
-- triggers will fire, too
create function noticetrigger() returns trigger as $$
begin
raise notice 'noticetrigger % %', new.f1, new.data;
return null;
end $$ language plpgsql;
create trigger tnoticetrigger after insert on tt for each row
execute procedure noticetrigger();
select insert_tt2('foolme','barme') limit 1;
NOTICE: noticetrigger 11 foolme
CONTEXT: SQL function "insert_tt2" statement 1
NOTICE: noticetrigger 12 barme
CONTEXT: SQL function "insert_tt2" statement 1
insert_tt2
------------
11
(1 row)
select * from tt;
f1 | data
----+----------
1 | foo
2 | bar
3 | fool
4 | foolfool
5 | foolish
6 | barrish
7 | baz
8 | quux
9 | foolish
10 | barrish
11 | foolme
12 | barme
(12 rows)
-- and rules work
create temp table tt_log(f1 int, data text);
create rule insert_tt_rule as on insert to tt do also
insert into tt_log values(new.*);
select insert_tt2('foollog','barlog') limit 1;
NOTICE: noticetrigger 13 foollog
CONTEXT: SQL function "insert_tt2" statement 1
NOTICE: noticetrigger 14 barlog
CONTEXT: SQL function "insert_tt2" statement 1
insert_tt2
------------
13
(1 row)
select * from tt;
f1 | data
----+----------
1 | foo
2 | bar
3 | fool
4 | foolfool
5 | foolish
6 | barrish
7 | baz
8 | quux
9 | foolish
10 | barrish
11 | foolme
12 | barme
13 | foollog
14 | barlog
(14 rows)
-- note that nextval() gets executed a second time in the rule expansion,
-- which is expected.
select * from tt_log;
f1 | data
----+---------
15 | foollog
16 | barlog
(2 rows)

View File

@ -61,7 +61,7 @@ LINE 2: AS 'not even SQL';
CREATE FUNCTION test1 (int) RETURNS int LANGUAGE SQL
AS 'SELECT 1, 2, 3;';
ERROR: return type mismatch in function declared to return integer
DETAIL: Final SELECT must return exactly one column.
DETAIL: Final statement must return exactly one column.
CONTEXT: SQL function "test1"
CREATE FUNCTION test1 (int) RETURNS int LANGUAGE SQL
AS 'SELECT $2;';

View File

@ -279,3 +279,62 @@ AS $$ SELECT a, b
generate_series(1,$1) b(b) $$ LANGUAGE sql;
SELECT * FROM foo(3);
DROP FUNCTION foo(int);
--
-- some tests on SQL functions with RETURNING
--
create temp table tt(f1 serial, data text);
create function insert_tt(text) returns int as
$$ insert into tt(data) values($1) returning f1 $$
language sql;
select insert_tt('foo');
select insert_tt('bar');
select * from tt;
-- insert will execute to completion even if function needs just 1 row
create or replace function insert_tt(text) returns int as
$$ insert into tt(data) values($1),($1||$1) returning f1 $$
language sql;
select insert_tt('fool');
select * from tt;
-- setof does what's expected
create or replace function insert_tt2(text,text) returns setof int as
$$ insert into tt(data) values($1),($2) returning f1 $$
language sql;
select insert_tt2('foolish','barrish');
select * from insert_tt2('baz','quux');
select * from tt;
-- limit doesn't prevent execution to completion
select insert_tt2('foolish','barrish') limit 1;
select * from tt;
-- triggers will fire, too
create function noticetrigger() returns trigger as $$
begin
raise notice 'noticetrigger % %', new.f1, new.data;
return null;
end $$ language plpgsql;
create trigger tnoticetrigger after insert on tt for each row
execute procedure noticetrigger();
select insert_tt2('foolme','barme') limit 1;
select * from tt;
-- and rules work
create temp table tt_log(f1 int, data text);
create rule insert_tt_rule as on insert to tt do also
insert into tt_log values(new.*);
select insert_tt2('foollog','barlog') limit 1;
select * from tt;
-- note that nextval() gets executed a second time in the rule expansion,
-- which is expected.
select * from tt_log;