Commit 913bbd88 authored by Tom Lane's avatar Tom Lane

Improve the handling of result type coercions in SQL functions.

Use the parser's standard type coercion machinery to convert the
output column(s) of a SQL function's final SELECT or RETURNING
to the type(s) they should have according to the function's declared
result type.  We'll allow any case where an assignment-level
coercion is available.  Previously, we failed unless the required
coercion was a binary-compatible one (and the documentation ignored
this, falsely claiming that the types must match exactly).

Notably, the coercion now accounts for typmods, so that cases where
a SQL function is declared to return a composite type whose columns
are typmod-constrained now behave as one would expect.  Arguably
this aspect is a bug fix, but the overall behavioral change here
seems too large to consider back-patching.

A nice side-effect is that functions can now be inlined in a
few cases where we previously failed to do so because of type
mismatches.

Discussion: https://postgr.es/m/18929.1574895430@sss.pgh.pa.us
parent 8dd1511e
......@@ -388,11 +388,15 @@ $$ LANGUAGE SQL;
</para>
<para>
A <acronym>SQL</acronym> function must return exactly its declared
result type. This may require inserting an explicit cast.
If the final <literal>SELECT</literal> or <literal>RETURNING</literal>
clause in a <acronym>SQL</acronym> function does not return exactly
the function's declared result
type, <productname>PostgreSQL</productname> will automatically cast
the value to the required type, if that is possible with an implicit
or assignment cast. Otherwise, you must write an explicit cast.
For example, suppose we wanted the
previous <function>add_em</function> function to return
type <type>float8</type> instead. This won't work:
type <type>float8</type> instead. It's sufficient to write
<programlisting>
CREATE FUNCTION add_em(integer, integer) RETURNS float8 AS $$
......@@ -400,16 +404,10 @@ CREATE FUNCTION add_em(integer, integer) RETURNS float8 AS $$
$$ LANGUAGE SQL;
</programlisting>
even though in other contexts <productname>PostgreSQL</productname>
would be willing to insert an implicit cast to
convert <type>integer</type> to <type>float8</type>.
We need to write it as
<programlisting>
CREATE FUNCTION add_em(integer, integer) RETURNS float8 AS $$
SELECT ($1 + $2)::float8;
$$ LANGUAGE SQL;
</programlisting>
since the <type>integer</type> sum can be implicitly cast
to <type>float8</type>.
(See <xref linkend="typeconv"/> or <xref linkend="sql-createcast"/>
for more about casts.)
</para>
</sect2>
......@@ -503,23 +501,24 @@ $$ LANGUAGE SQL;
<listitem>
<para>
The select list order in the query must be exactly the same as
that in which the columns appear in the table associated
with the composite type. (Naming the columns, as we did above,
that in which the columns appear in the composite type.
(Naming the columns, as we did above,
is irrelevant to the system.)
</para>
</listitem>
<listitem>
<para>
We must ensure each expression's type matches the corresponding
column of the composite type, inserting a cast if necessary.
We must ensure each expression's type can be cast to that of
the corresponding column of the composite type.
Otherwise we'll get errors like this:
<screen>
<computeroutput>
ERROR: function declared to return emp returns varchar instead of text at column 1
ERROR: return type mismatch in function declared to return emp
DETAIL: Final statement returns text instead of point at column 4.
</computeroutput>
</screen>
As with the base-type case, the function will not insert any casts
automatically.
As with the base-type case, the system will not insert explicit
casts automatically, only implicit or assignment casts.
</para>
</listitem>
</itemizedlist>
......@@ -542,8 +541,7 @@ $$ LANGUAGE SQL;
Another example is that if we are trying to write a function that
returns a domain over composite, rather than a plain composite type,
it is always necessary to write it as returning a single column,
since there is no other way to produce a value that is exactly of
the domain type.
since there is no way to cause a coercion of the whole row result.
</para>
<para>
......@@ -1263,7 +1261,7 @@ SELECT make_array(1, 2) AS intarray, make_array('a'::text, 'b') AS textarray;
Without the typecast, you will get errors like this:
<screen>
<computeroutput>
ERROR: could not determine polymorphic type because input has type "unknown"
ERROR: could not determine polymorphic type because input has type unknown
</computeroutput>
</screen>
</para>
......
......@@ -923,6 +923,8 @@ fmgr_sql_validator(PG_FUNCTION_ARGS)
* verify the result type.
*/
SQLFunctionParseInfoPtr pinfo;
Oid rettype;
TupleDesc rettupdesc;
/* But first, set up parameter information */
pinfo = prepare_sql_fn_parse_info(tuple, NULL, InvalidOid);
......@@ -943,9 +945,12 @@ fmgr_sql_validator(PG_FUNCTION_ARGS)
}
check_sql_fn_statements(querytree_list);
(void) check_sql_fn_retval(funcoid, proc->prorettype,
querytree_list,
NULL, NULL);
(void) get_func_result_type(funcoid, &rettype, &rettupdesc);
(void) check_sql_fn_retval(querytree_list,
rettype, rettupdesc,
false, NULL);
}
error_context_stack = sqlerrcontext.previous;
......
This diff is collapsed.
......@@ -155,7 +155,6 @@ static Query *substitute_actual_srf_parameters(Query *expr,
int nargs, List *args);
static Node *substitute_actual_srf_parameters_mutator(Node *node,
substitute_actual_srf_parameters_context *context);
static bool tlist_matches_coltypelist(List *tlist, List *coltypelist);
/*****************************************************************************
......@@ -4399,15 +4398,16 @@ inline_function(Oid funcid, Oid result_type, Oid result_collid,
char *src;
Datum tmp;
bool isNull;
bool modifyTargetList;
MemoryContext oldcxt;
MemoryContext mycxt;
inline_error_callback_arg callback_arg;
ErrorContextCallback sqlerrcontext;
FuncExpr *fexpr;
SQLFunctionParseInfoPtr pinfo;
TupleDesc rettupdesc;
ParseState *pstate;
List *raw_parsetree_list;
List *querytree_list;
Query *querytree;
Node *newexpr;
int *usecounts;
......@@ -4472,8 +4472,8 @@ inline_function(Oid funcid, Oid result_type, Oid result_collid,
/*
* Set up to handle parameters while parsing the function body. We need a
* dummy FuncExpr node containing the already-simplified arguments to pass
* to prepare_sql_fn_parse_info. (It is really only needed if there are
* some polymorphic arguments, but for simplicity we always build it.)
* to prepare_sql_fn_parse_info. (In some cases we don't really need
* that, but for simplicity we always build it.)
*/
fexpr = makeNode(FuncExpr);
fexpr->funcid = funcid;
......@@ -4490,6 +4490,11 @@ inline_function(Oid funcid, Oid result_type, Oid result_collid,
(Node *) fexpr,
input_collid);
/* fexpr also provides a convenient way to resolve a composite result */
(void) get_expr_result_type((Node *) fexpr,
NULL,
&rettupdesc);
/*
* We just do parsing and parse analysis, not rewriting, because rewriting
* will not affect table-free-SELECT-only queries, which is all that we
......@@ -4542,16 +4547,24 @@ inline_function(Oid funcid, Oid result_type, Oid result_collid,
* Make sure the function (still) returns what it's declared to. This
* will raise an error if wrong, but that's okay since the function would
* fail at runtime anyway. Note that check_sql_fn_retval will also insert
* a RelabelType if needed to make the tlist expression match the declared
* a coercion if needed to make the tlist expression match the declared
* type of the function.
*
* Note: we do not try this until we have verified that no rewriting was
* needed; that's probably not important, but let's be careful.
*/
if (check_sql_fn_retval(funcid, result_type, list_make1(querytree),
&modifyTargetList, NULL))
querytree_list = list_make1(querytree);
if (check_sql_fn_retval(querytree_list, result_type, rettupdesc,
false, NULL))
goto fail; /* reject whole-tuple-result cases */
/*
* Given the tests above, check_sql_fn_retval shouldn't have decided to
* inject a projection step, but let's just make sure.
*/
if (querytree != linitial(querytree_list))
goto fail;
/* Now we can grab the tlist expression */
newexpr = (Node *) ((TargetEntry *) linitial(querytree->targetList))->expr;
......@@ -4566,9 +4579,6 @@ inline_function(Oid funcid, Oid result_type, Oid result_collid,
if (exprType(newexpr) != result_type)
goto fail;
/* check_sql_fn_retval couldn't have made any dangerous tlist changes */
Assert(!modifyTargetList);
/*
* Additional validity checks on the expression. It mustn't be more
* volatile than the surrounding function (this is to avoid breaking hacks
......@@ -4877,12 +4887,13 @@ inline_set_returning_function(PlannerInfo *root, RangeTblEntry *rte)
char *src;
Datum tmp;
bool isNull;
bool modifyTargetList;
MemoryContext oldcxt;
MemoryContext mycxt;
inline_error_callback_arg callback_arg;
ErrorContextCallback sqlerrcontext;
SQLFunctionParseInfoPtr pinfo;
TypeFuncClass functypclass;
TupleDesc rettupdesc;
List *raw_parsetree_list;
List *querytree_list;
Query *querytree;
......@@ -5012,6 +5023,18 @@ inline_set_returning_function(PlannerInfo *root, RangeTblEntry *rte)
(Node *) fexpr,
fexpr->inputcollid);
/*
* Also resolve the actual function result tupdesc, if composite. If the
* function is just declared to return RECORD, dig the info out of the AS
* clause.
*/
functypclass = get_expr_result_type((Node *) fexpr, NULL, &rettupdesc);
if (functypclass == TYPEFUNC_RECORD)
rettupdesc = BuildDescFromLists(rtfunc->funccolnames,
rtfunc->funccoltypes,
rtfunc->funccoltypmods,
rtfunc->funccolcollations);
/*
* Parse, analyze, and rewrite (unlike inline_function(), we can't skip
* rewriting here). We can fail as soon as we find more than one query,
......@@ -5040,43 +5063,28 @@ inline_set_returning_function(PlannerInfo *root, RangeTblEntry *rte)
* Make sure the function (still) returns what it's declared to. This
* will raise an error if wrong, but that's okay since the function would
* fail at runtime anyway. Note that check_sql_fn_retval will also insert
* RelabelType(s) and/or NULL columns if needed to make the tlist
* expression(s) match the declared type of the function.
* coercions if needed to make the tlist expression(s) match the declared
* type of the function. We also ask it to insert dummy NULL columns for
* any dropped columns in rettupdesc, so that the elements of the modified
* tlist match up to the attribute numbers.
*
* If the function returns a composite type, don't inline unless the check
* shows it's returning a whole tuple result; otherwise what it's
* returning is a single composite column which is not what we need. (Like
* check_sql_fn_retval, we deliberately exclude domains over composite
* here.)
* returning is a single composite column which is not what we need.
*/
if (!check_sql_fn_retval(func_oid, fexpr->funcresulttype,
querytree_list,
&modifyTargetList, NULL) &&
(get_typtype(fexpr->funcresulttype) == TYPTYPE_COMPOSITE ||
fexpr->funcresulttype == RECORDOID))
if (!check_sql_fn_retval(querytree_list,
fexpr->funcresulttype, rettupdesc,
true, NULL) &&
(functypclass == TYPEFUNC_COMPOSITE ||
functypclass == TYPEFUNC_COMPOSITE_DOMAIN ||
functypclass == TYPEFUNC_RECORD))
goto fail; /* reject not-whole-tuple-result cases */
/*
* If we had to modify the tlist to make it match, and the statement is
* one in which changing the tlist contents could change semantics, we
* have to punt and not inline.
*/
if (modifyTargetList)
goto fail;
/*
* If it returns RECORD, we have to check against the column type list
* provided in the RTE; check_sql_fn_retval can't do that. (If no match,
* we just fail to inline, rather than complaining; see notes for
* tlist_matches_coltypelist.) We don't have to do this for functions
* with declared OUT parameters, even though their funcresulttype is
* RECORDOID, so check get_func_result_type too.
* check_sql_fn_retval might've inserted a projection step, but that's
* fine; just make sure we use the upper Query.
*/
if (fexpr->funcresulttype == RECORDOID &&
get_func_result_type(func_oid, NULL, NULL) == TYPEFUNC_RECORD &&
!tlist_matches_coltypelist(querytree->targetList,
rtfunc->funccoltypes))
goto fail;
querytree = linitial(querytree_list);
/*
* Looks good --- substitute parameters into the query.
......@@ -5181,46 +5189,3 @@ substitute_actual_srf_parameters_mutator(Node *node,
substitute_actual_srf_parameters_mutator,
(void *) context);
}
/*
* Check whether a SELECT targetlist emits the specified column types,
* to see if it's safe to inline a function returning record.
*
* We insist on exact match here. The executor allows binary-coercible
* cases too, but we don't have a way to preserve the correct column types
* in the correct places if we inline the function in such a case.
*
* Note that we only check type OIDs not typmods; this agrees with what the
* executor would do at runtime, and attributing a specific typmod to a
* function result is largely wishful thinking anyway.
*/
static bool
tlist_matches_coltypelist(List *tlist, List *coltypelist)
{
ListCell *tlistitem;
ListCell *clistitem;
clistitem = list_head(coltypelist);
foreach(tlistitem, tlist)
{
TargetEntry *tle = (TargetEntry *) lfirst(tlistitem);
Oid coltype;
if (tle->resjunk)
continue; /* ignore junk columns */
if (clistitem == NULL)
return false; /* too many tlist items */
coltype = lfirst_oid(clistitem);
clistitem = lnext(coltypelist, clistitem);
if (exprType((Node *) tle->expr) != coltype)
return false; /* column type mismatch */
}
if (clistitem != NULL)
return false; /* too few tlist items */
return true;
}
......@@ -31,10 +31,10 @@ extern void sql_fn_parser_setup(struct ParseState *pstate,
extern void check_sql_fn_statements(List *queryTreeList);
extern bool check_sql_fn_retval(Oid func_id, Oid rettype,
List *queryTreeList,
bool *modifyTargetList,
JunkFilter **junkFilter);
extern bool check_sql_fn_retval(List *queryTreeList,
Oid rettype, TupleDesc rettupdesc,
bool insertDroppedCols,
List **resultTargetList);
extern DestReceiver *CreateSQLFunctionDestReceiver(void);
......
......@@ -1820,6 +1820,67 @@ select * from array_to_set(array['one', 'two']); -- fail
ERROR: a column definition list is required for functions returning "record"
LINE 1: select * from array_to_set(array['one', 'two']);
^
-- after-the-fact coercion of the columns is now possible, too
select * from array_to_set(array['one', 'two']) as t(f1 numeric(4,2),f2 text);
f1 | f2
------+-----
1.00 | one
2.00 | two
(2 rows)
-- and if it doesn't work, you get a compile-time not run-time error
select * from array_to_set(array['one', 'two']) as t(f1 point,f2 text);
ERROR: return type mismatch in function declared to return record
DETAIL: Final statement returns integer instead of point at column 1.
CONTEXT: SQL function "array_to_set" during startup
-- with "strict", this function can't be inlined in FROM
explain (verbose, costs off)
select * from array_to_set(array['one', 'two']) as t(f1 numeric(4,2),f2 text);
QUERY PLAN
----------------------------------------------------
Function Scan on public.array_to_set t
Output: f1, f2
Function Call: array_to_set('{one,two}'::text[])
(3 rows)
-- but without, it can be:
create or replace function array_to_set(anyarray) returns setof record as $$
select i AS "index", $1[i] AS "value" from generate_subscripts($1, 1) i
$$ language sql immutable;
select array_to_set(array['one', 'two']);
array_to_set
--------------
(1,one)
(2,two)
(2 rows)
select * from array_to_set(array['one', 'two']) as t(f1 int,f2 text);
f1 | f2
----+-----
1 | one
2 | two
(2 rows)
select * from array_to_set(array['one', 'two']) as t(f1 numeric(4,2),f2 text);
f1 | f2
------+-----
1.00 | one
2.00 | two
(2 rows)
select * from array_to_set(array['one', 'two']) as t(f1 point,f2 text);
ERROR: return type mismatch in function declared to return record
DETAIL: Final statement returns integer instead of point at column 1.
CONTEXT: SQL function "array_to_set" during inlining
explain (verbose, costs off)
select * from array_to_set(array['one', 'two']) as t(f1 numeric(4,2),f2 text);
QUERY PLAN
--------------------------------------------------------------
Function Scan on pg_catalog.generate_subscripts i
Output: i.i, ('{one,two}'::text[])[i.i]
Function Call: generate_subscripts('{one,two}'::text[], 1)
(3 rows)
create temp table rngfunc(f1 int8, f2 int8);
create function testrngfunc() returns record as $$
insert into rngfunc values (1,2) returning *;
......@@ -1863,6 +1924,140 @@ ERROR: a column definition list is required for functions returning "record"
LINE 1: select * from testrngfunc();
^
drop function testrngfunc();
-- Check that typmod imposed by a composite type is honored
create type rngfunc_type as (f1 numeric(35,6), f2 numeric(35,2));
create function testrngfunc() returns rngfunc_type as $$
select 7.136178319899999964, 7.136178319899999964;
$$ language sql immutable;
explain (verbose, costs off)
select testrngfunc();
QUERY PLAN
-------------------------------------------
Result
Output: '(7.136178,7.14)'::rngfunc_type
(2 rows)
select testrngfunc();
testrngfunc
-----------------
(7.136178,7.14)
(1 row)
explain (verbose, costs off)
select * from testrngfunc();
QUERY PLAN
--------------------------------------------------
Function Scan on testrngfunc
Output: f1, f2
Function Call: '(7.136178,7.14)'::rngfunc_type
(3 rows)
select * from testrngfunc();
f1 | f2
----------+------
7.136178 | 7.14
(1 row)
create or replace function testrngfunc() returns rngfunc_type as $$
select 7.136178319899999964, 7.136178319899999964;
$$ language sql volatile;
explain (verbose, costs off)
select testrngfunc();
QUERY PLAN
-------------------------
Result
Output: testrngfunc()
(2 rows)
select testrngfunc();
testrngfunc
-----------------
(7.136178,7.14)
(1 row)
explain (verbose, costs off)
select * from testrngfunc();
QUERY PLAN
-------------------------------------
Function Scan on public.testrngfunc
Output: f1, f2
Function Call: testrngfunc()
(3 rows)
select * from testrngfunc();
f1 | f2
----------+------
7.136178 | 7.14
(1 row)
drop function testrngfunc();
create function testrngfunc() returns setof rngfunc_type as $$
select 7.136178319899999964, 7.136178319899999964;
$$ language sql immutable;
explain (verbose, costs off)
select testrngfunc();
QUERY PLAN
-------------------------
ProjectSet
Output: testrngfunc()
-> Result
(3 rows)
select testrngfunc();
testrngfunc
-----------------
(7.136178,7.14)
(1 row)
explain (verbose, costs off)
select * from testrngfunc();
QUERY PLAN
--------------------------------------------------------
Result
Output: 7.136178::numeric(35,6), 7.14::numeric(35,2)
(2 rows)
select * from testrngfunc();
f1 | f2
----------+------
7.136178 | 7.14
(1 row)
create or replace function testrngfunc() returns setof rngfunc_type as $$
select 7.136178319899999964, 7.136178319899999964;
$$ language sql volatile;
explain (verbose, costs off)
select testrngfunc();
QUERY PLAN
-------------------------
ProjectSet
Output: testrngfunc()
-> Result
(3 rows)
select testrngfunc();
testrngfunc
-----------------
(7.136178,7.14)
(1 row)
explain (verbose, costs off)
select * from testrngfunc();
QUERY PLAN
-------------------------------------
Function Scan on public.testrngfunc
Output: f1, f2
Function Call: testrngfunc()
(3 rows)
select * from testrngfunc();
f1 | f2
----------+------
7.136178 | 7.14
(1 row)
drop type rngfunc_type cascade;
NOTICE: drop cascades to function testrngfunc()
--
-- Check some cases involving added/dropped columns in a rowtype result
--
......@@ -1955,7 +2150,7 @@ drop view usersview;
drop function get_first_user();
drop function get_users();
drop table users;
-- this won't get inlined because of type coercion, but it shouldn't fail
-- check behavior with type coercion required for a set-op
create or replace function rngfuncbar() returns setof text as
$$ select 'foo'::varchar union all select 'bar'::varchar ; $$
language sql stable;
......@@ -1973,6 +2168,19 @@ select * from rngfuncbar();
bar
(2 rows)
-- this function is now inlinable, too:
explain (verbose, costs off) select * from rngfuncbar();
QUERY PLAN
------------------------------------------------
Result
Output: ('foo'::character varying)
-> Append
-> Result
Output: 'foo'::character varying
-> Result
Output: 'bar'::character varying
(7 rows)
drop function rngfuncbar();
-- check handling of a SQL function with multiple OUT params (bug #5777)
create or replace function rngfuncbar(out integer, out numeric) as
......
......@@ -515,6 +515,27 @@ $$ language sql strict immutable;
select array_to_set(array['one', 'two']);
select * from array_to_set(array['one', 'two']) as t(f1 int,f2 text);
select * from array_to_set(array['one', 'two']); -- fail
-- after-the-fact coercion of the columns is now possible, too
select * from array_to_set(array['one', 'two']) as t(f1 numeric(4,2),f2 text);
-- and if it doesn't work, you get a compile-time not run-time error
select * from array_to_set(array['one', 'two']) as t(f1 point,f2 text);
-- with "strict", this function can't be inlined in FROM
explain (verbose, costs off)
select * from array_to_set(array['one', 'two']) as t(f1 numeric(4,2),f2 text);
-- but without, it can be:
create or replace function array_to_set(anyarray) returns setof record as $$
select i AS "index", $1[i] AS "value" from generate_subscripts($1, 1) i
$$ language sql immutable;
select array_to_set(array['one', 'two']);
select * from array_to_set(array['one', 'two']) as t(f1 int,f2 text);
select * from array_to_set(array['one', 'two']) as t(f1 numeric(4,2),f2 text);
select * from array_to_set(array['one', 'two']) as t(f1 point,f2 text);
explain (verbose, costs off)
select * from array_to_set(array['one', 'two']) as t(f1 numeric(4,2),f2 text);
create temp table rngfunc(f1 int8, f2 int8);
......@@ -538,6 +559,57 @@ select * from testrngfunc(); -- fail
drop function testrngfunc();
-- Check that typmod imposed by a composite type is honored
create type rngfunc_type as (f1 numeric(35,6), f2 numeric(35,2));
create function testrngfunc() returns rngfunc_type as $$
select 7.136178319899999964, 7.136178319899999964;
$$ language sql immutable;
explain (verbose, costs off)
select testrngfunc();
select testrngfunc();
explain (verbose, costs off)
select * from testrngfunc();
select * from testrngfunc();
create or replace function testrngfunc() returns rngfunc_type as $$
select 7.136178319899999964, 7.136178319899999964;
$$ language sql volatile;
explain (verbose, costs off)
select testrngfunc();
select testrngfunc();
explain (verbose, costs off)
select * from testrngfunc();
select * from testrngfunc();
drop function testrngfunc();
create function testrngfunc() returns setof rngfunc_type as $$
select 7.136178319899999964, 7.136178319899999964;
$$ language sql immutable;
explain (verbose, costs off)
select testrngfunc();
select testrngfunc();
explain (verbose, costs off)
select * from testrngfunc();
select * from testrngfunc();
create or replace function testrngfunc() returns setof rngfunc_type as $$
select 7.136178319899999964, 7.136178319899999964;
$$ language sql volatile;
explain (verbose, costs off)
select testrngfunc();
select testrngfunc();
explain (verbose, costs off)
select * from testrngfunc();
select * from testrngfunc();
drop type rngfunc_type cascade;
--
-- Check some cases involving added/dropped columns in a rowtype result
--
......@@ -585,7 +657,7 @@ drop function get_first_user();
drop function get_users();
drop table users;
-- this won't get inlined because of type coercion, but it shouldn't fail
-- check behavior with type coercion required for a set-op
create or replace function rngfuncbar() returns setof text as
$$ select 'foo'::varchar union all select 'bar'::varchar ; $$
......@@ -593,6 +665,8 @@ language sql stable;
select rngfuncbar();
select * from rngfuncbar();
-- this function is now inlinable, too:
explain (verbose, costs off) select * from rngfuncbar();
drop function rngfuncbar();
......
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