Skip to content

Commit 0dca5d6

Browse files
committed
Change SQL-language functions to use the plan cache.
In the historical implementation of SQL functions (if they don't get inlined), we built plans for all the contained queries at first call within an outer query, and then re-used those plans for the duration of the outer query, and then forgot everything. This was not ideal, not least because the plans could not be customized to specific values of the function's parameters. Our plancache infrastructure seems mature enough to be used here. That will solve both the problem with not being able to build custom plans and the problem with not being able to share work across successive outer queries. Aside from those performance concerns, this change fixes a longstanding bugaboo with SQL functions: you could not write DDL that would affect later statements in the same function. That's mostly still true with new-style SQL functions, since the results of parse analysis are baked into the stored query trees (and protected by dependency records). But for old-style SQL functions, it will now work much as it does with PL/pgSQL functions, because we delay parse analysis and planning of each query until we're ready to run it. Some edge cases that require replanning are now handled better too; see for example the new rowsecurity test, where we now detect an RLS context change that was previously missed. One other edge-case change that might be worthy of a release note is that we now insist that a SQL function's result be generated by the physically-last query within it. Previously, if the last original query was deleted by a DO INSTEAD NOTHING rule, we'd be willing to take the result from the preceding query instead. This behavior was undocumented except in source-code comments, and it seems hard to believe that anyone's relying on it. Along the way to this feature, we needed a few infrastructure changes: * The plancache can now take either a raw parse tree or an analyzed-but-not-rewritten Query as the starting point for a CachedPlanSource. If given a Query, it is caller's responsibility that nothing will happen to invalidate that form of the query. We use this for new-style SQL functions, where what's in pg_proc is serialized Query(s) and we trust the dependency mechanism to disallow DDL that would break those. * The plancache now offers a way to invoke a post-rewrite callback to examine/modify the rewritten parse tree when it is rebuilding the parse trees after a cache invalidation. We need this because SQL functions sometimes adjust the parse tree to make its output exactly match the declared result type; if the plan gets rebuilt, that has to be re-done. * There is a new backend module utils/cache/funccache.c that abstracts the idea of caching data about a specific function usage (a particular function and set of input data types). The code in it is moved almost verbatim from PL/pgSQL, which has done that for a long time. We use that logic now for SQL-language functions too, and maybe other PLs will have use for it in the future. Author: Alexander Pyhalov <[email protected]> Co-authored-by: Tom Lane <[email protected]> Reviewed-by: Pavel Stehule <[email protected]> Discussion: https://postgr.es/m/8216639.NyiUUSuA9g@aivenlaptop
1 parent e9e7b66 commit 0dca5d6

File tree

24 files changed

+2132
-989
lines changed

24 files changed

+2132
-989
lines changed

doc/src/sgml/xfunc.sgml

-15
Original file line numberDiff line numberDiff line change
@@ -234,21 +234,6 @@ CALL clean_emp();
234234
whereas returning <type>void</type> is a PostgreSQL extension.
235235
</para>
236236

237-
<note>
238-
<para>
239-
The entire body of an SQL function is parsed before any of it is
240-
executed. While an SQL function can contain commands that alter
241-
the system catalogs (e.g., <command>CREATE TABLE</command>), the effects
242-
of such commands will not be visible during parse analysis of
243-
later commands in the function. Thus, for example,
244-
<literal>CREATE TABLE foo (...); INSERT INTO foo VALUES(...);</literal>
245-
will not work as desired if packaged up into a single SQL function,
246-
since <structname>foo</structname> won't exist yet when the <command>INSERT</command>
247-
command is parsed. It's recommended to use <application>PL/pgSQL</application>
248-
instead of an SQL function in this type of situation.
249-
</para>
250-
</note>
251-
252237
<para>
253238
The syntax of the <command>CREATE FUNCTION</command> command requires
254239
the function body to be written as a string constant. It is usually

src/backend/catalog/pg_proc.c

+1-1
Original file line numberDiff line numberDiff line change
@@ -960,7 +960,7 @@ fmgr_sql_validator(PG_FUNCTION_ARGS)
960960
(void) check_sql_fn_retval(querytree_list,
961961
rettype, rettupdesc,
962962
proc->prokind,
963-
false, NULL);
963+
false);
964964
}
965965

966966
error_context_stack = sqlerrcontext.previous;

0 commit comments

Comments
 (0)