On 20.02.23 13:58, Peter Eisentraut wrote:
The attached patches are the same as before, rebased over master and split up as described.  I haven't done any significant work on the contents, but I will try to get the 0001 patch into a more polished state soon.

I've done a bit of work on this patch, mainly cleaned up and expanded the tests, and also added DO support, which is something that had been requested (meaning you can return result sets from DO with this facility). Here is a new version.
From ada315925d02883833cc5f4bc95477b0217d9d66 Mon Sep 17 00:00:00 2001
From: Peter Eisentraut <pe...@eisentraut.org>
Date: Fri, 24 Feb 2023 12:21:40 +0100
Subject: [PATCH v8 1/2] Dynamic result sets from procedures

Declaring a cursor WITH RETURN in a procedure makes the cursor's data
be returned as a result of the CALL (or DO) invocation.  The procedure
needs to be declared with the DYNAMIC RESULT SETS attribute.

Discussion: 
https://www.postgresql.org/message-id/flat/6e747f98-835f-2e05-cde5-86ee444a7...@2ndquadrant.com
---
 doc/src/sgml/catalogs.sgml                    |  10 ++
 doc/src/sgml/information_schema.sgml          |   3 +-
 doc/src/sgml/plpgsql.sgml                     |  27 +++-
 doc/src/sgml/ref/alter_procedure.sgml         |  12 ++
 doc/src/sgml/ref/create_procedure.sgml        |  14 ++
 doc/src/sgml/ref/declare.sgml                 |  35 ++++-
 src/backend/catalog/information_schema.sql    |   2 +-
 src/backend/catalog/pg_aggregate.c            |   3 +-
 src/backend/catalog/pg_proc.c                 |   4 +-
 src/backend/catalog/sql_features.txt          |   2 +-
 src/backend/commands/functioncmds.c           |  94 +++++++++++--
 src/backend/commands/portalcmds.c             |  23 ++++
 src/backend/commands/typecmds.c               |  12 +-
 src/backend/parser/gram.y                     |  18 ++-
 src/backend/tcop/postgres.c                   |  37 ++++-
 src/backend/utils/errcodes.txt                |   1 +
 src/backend/utils/mmgr/portalmem.c            |  48 +++++++
 src/bin/pg_dump/pg_dump.c                     |  16 ++-
 src/include/catalog/pg_proc.h                 |   6 +-
 src/include/commands/defrem.h                 |   1 +
 src/include/nodes/parsenodes.h                |   1 +
 src/include/parser/kwlist.h                   |   2 +
 src/include/utils/portal.h                    |  12 ++
 src/pl/plpgsql/src/Makefile                   |   2 +-
 .../src/expected/plpgsql_with_return.out      | 105 ++++++++++++++
 src/pl/plpgsql/src/meson.build                |   1 +
 src/pl/plpgsql/src/pl_exec.c                  |   6 +
 src/pl/plpgsql/src/pl_gram.y                  |  58 +++++++-
 src/pl/plpgsql/src/pl_unreserved_kwlist.h     |   2 +
 .../plpgsql/src/sql/plpgsql_with_return.sql   |  64 +++++++++
 .../regress/expected/dynamic_result_sets.out  | 129 ++++++++++++++++++
 src/test/regress/parallel_schedule            |   2 +-
 src/test/regress/sql/dynamic_result_sets.sql  |  90 ++++++++++++
 33 files changed, 803 insertions(+), 39 deletions(-)
 create mode 100644 src/pl/plpgsql/src/expected/plpgsql_with_return.out
 create mode 100644 src/pl/plpgsql/src/sql/plpgsql_with_return.sql
 create mode 100644 src/test/regress/expected/dynamic_result_sets.out
 create mode 100644 src/test/regress/sql/dynamic_result_sets.sql

diff --git a/doc/src/sgml/catalogs.sgml b/doc/src/sgml/catalogs.sgml
index c1e4048054..5baec4dc3a 100644
--- a/doc/src/sgml/catalogs.sgml
+++ b/doc/src/sgml/catalogs.sgml
@@ -6041,6 +6041,16 @@ <title><structname>pg_proc</structname> Columns</title>
       </para></entry>
      </row>
 
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>prodynres</structfield> <type>int4</type>
+      </para>
+      <para>
+       For procedures, this records the maximum number of dynamic result sets
+       the procedure may create.  Otherwise zero.
+      </para></entry>
+     </row>
+
      <row>
       <entry role="catalog_table_entry"><para role="column_definition">
        <structfield>pronargs</structfield> <type>int2</type>
diff --git a/doc/src/sgml/information_schema.sgml 
b/doc/src/sgml/information_schema.sgml
index 350c75bc31..5fc9dc22ae 100644
--- a/doc/src/sgml/information_schema.sgml
+++ b/doc/src/sgml/information_schema.sgml
@@ -5885,7 +5885,8 @@ <title><structname>routines</structname> Columns</title>
        <structfield>max_dynamic_result_sets</structfield> 
<type>cardinal_number</type>
       </para>
       <para>
-       Applies to a feature not available in 
<productname>PostgreSQL</productname>
+       For a procedure, the maximum number of dynamic result sets.  Otherwise
+       zero.
       </para></entry>
      </row>
 
diff --git a/doc/src/sgml/plpgsql.sgml b/doc/src/sgml/plpgsql.sgml
index 8897a5450a..0c0d77b0e6 100644
--- a/doc/src/sgml/plpgsql.sgml
+++ b/doc/src/sgml/plpgsql.sgml
@@ -3128,7 +3128,7 @@ <title>Declaring Cursor Variables</title>
      Another way is to use the cursor declaration syntax,
      which in general is:
 <synopsis>
-<replaceable>name</replaceable> <optional> <optional> NO </optional> SCROLL 
</optional> CURSOR <optional> ( <replaceable>arguments</replaceable> ) 
</optional> FOR <replaceable>query</replaceable>;
+<replaceable>name</replaceable> <optional> <optional> NO </optional> SCROLL 
</optional> CURSOR <optional> <optional> WITH RETURN </optional> ( 
<replaceable>arguments</replaceable> ) </optional> FOR 
<replaceable>query</replaceable>;
 </synopsis>
      (<literal>FOR</literal> can be replaced by <literal>IS</literal> for
      <productname>Oracle</productname> compatibility.)
@@ -3136,6 +3136,10 @@ <title>Declaring Cursor Variables</title>
      scrolling backward; if <literal>NO SCROLL</literal> is specified, backward
      fetches will be rejected; if neither specification appears, it is
      query-dependent whether backward fetches will be allowed.
+     If <literal>WITH RETURN</literal> is specified, the results of the
+     cursor, after it is opened, will be returned as a dynamic result set; see
+     <xref linkend="sql-declare"/> for details.  (<literal>WITHOUT
+     RETURN</literal> can also be specified but has no effect.)
      <replaceable>arguments</replaceable>, if specified, is a
      comma-separated list of pairs <literal><replaceable>name</replaceable>
      <replaceable>datatype</replaceable></literal> that define names to be
@@ -3215,7 +3219,7 @@ <title>Opening Cursors</title>
      <title><command>OPEN FOR</command> 
<replaceable>query</replaceable></title>
 
 <synopsis>
-OPEN <replaceable>unbound_cursorvar</replaceable> <optional> <optional> NO 
</optional> SCROLL </optional> FOR <replaceable>query</replaceable>;
+OPEN <replaceable>unbound_cursorvar</replaceable> <optional> <optional> NO 
</optional> SCROLL </optional> <optional> WITH RETURN </optional> FOR 
<replaceable>query</replaceable>;
 </synopsis>
 
        <para>
@@ -3233,8 +3237,9 @@ <title><command>OPEN FOR</command> 
<replaceable>query</replaceable></title>
         substituted is the one it has at the time of the 
<command>OPEN</command>;
         subsequent changes to the variable will not affect the cursor's
         behavior.
-        The <literal>SCROLL</literal> and <literal>NO SCROLL</literal>
-        options have the same meanings as for a bound cursor.
+        The options <literal>SCROLL</literal>, <literal>NO SCROLL</literal>,
+        and <literal>WITH RETURN</literal> have the same meanings as for a
+        bound cursor.
        </para>
 
        <para>
@@ -3612,6 +3617,20 @@ <title>Returning Cursors</title>
 COMMIT;
 </programlisting>
        </para>
+
+       <note>
+        <para>
+         Returning a cursor from a function as described here is a separate
+         mechanism from declaring a cursor <literal>WITH RETURN</literal>,
+         which automatically produces a result set for the client if the
+         cursor is left open when returning from the procedure.  Both
+         mechanisms can be used to achieve similar effects.  The differences
+         are mainly how the client application prefers to manage the cursors.
+         Furthermore, other SQL implementations have other programming models
+         that might map more easily to one or the other mechanism when doing a
+         migration.
+        </para>
+       </note>
      </sect3>
    </sect2>
 
diff --git a/doc/src/sgml/ref/alter_procedure.sgml 
b/doc/src/sgml/ref/alter_procedure.sgml
index a4737a3439..2cdda7730e 100644
--- a/doc/src/sgml/ref/alter_procedure.sgml
+++ b/doc/src/sgml/ref/alter_procedure.sgml
@@ -34,6 +34,7 @@
 
 <phrase>where <replaceable class="parameter">action</replaceable> is one 
of:</phrase>
 
+    DYNAMIC RESULT SETS <replaceable 
class="parameter">dynamic_result_sets</replaceable>
     [ EXTERNAL ] SECURITY INVOKER | [ EXTERNAL ] SECURITY DEFINER
     SET <replaceable class="parameter">configuration_parameter</replaceable> { 
TO | = } { <replaceable class="parameter">value</replaceable> | DEFAULT }
     SET <replaceable class="parameter">configuration_parameter</replaceable> 
FROM CURRENT
@@ -158,6 +159,17 @@ <title>Parameters</title>
     </listitem>
    </varlistentry>
 
+   <varlistentry>
+    <term><literal>DYNAMIC RESULT SETS <replaceable 
class="parameter">dynamic_result_sets</replaceable></literal></term>
+
+    <listitem>
+     <para>
+      Changes the dynamic result sets setting of the procedure.  See <xref
+      linkend="sql-createprocedure"/> for more information.
+     </para>
+    </listitem>
+   </varlistentry>
+
    <varlistentry>
     <term><literal><optional> EXTERNAL </optional> SECURITY 
INVOKER</literal></term>
     <term><literal><optional> EXTERNAL </optional> SECURITY 
DEFINER</literal></term>
diff --git a/doc/src/sgml/ref/create_procedure.sgml 
b/doc/src/sgml/ref/create_procedure.sgml
index 03a14c8684..1c99b00eef 100644
--- a/doc/src/sgml/ref/create_procedure.sgml
+++ b/doc/src/sgml/ref/create_procedure.sgml
@@ -24,6 +24,7 @@
 CREATE [ OR REPLACE ] PROCEDURE
     <replaceable class="parameter">name</replaceable> ( [ [ <replaceable 
class="parameter">argmode</replaceable> ] [ <replaceable 
class="parameter">argname</replaceable> ] <replaceable 
class="parameter">argtype</replaceable> [ { DEFAULT | = } <replaceable 
class="parameter">default_expr</replaceable> ] [, ...] ] )
   { LANGUAGE <replaceable class="parameter">lang_name</replaceable>
+    | DYNAMIC RESULT SETS <replaceable 
class="parameter">dynamic_result_sets</replaceable>
     | TRANSFORM { FOR TYPE <replaceable 
class="parameter">type_name</replaceable> } [, ... ]
     | [ EXTERNAL ] SECURITY INVOKER | [ EXTERNAL ] SECURITY DEFINER
     | SET <replaceable class="parameter">configuration_parameter</replaceable> 
{ TO <replaceable class="parameter">value</replaceable> | = <replaceable 
class="parameter">value</replaceable> | FROM CURRENT }
@@ -176,6 +177,19 @@ <title>Parameters</title>
      </listitem>
     </varlistentry>
 
+    <varlistentry>
+     <term><literal>DYNAMIC RESULT SETS <replaceable 
class="parameter">dynamic_result_sets</replaceable></literal></term>
+
+     <listitem>
+      <para>
+       Specifies how many dynamic result sets the procedure returns (see
+       <literal><link linkend="sql-declare">DECLARE</link> WITH
+       RETURN</literal>).  The default is 0.  If a procedure returns more
+       result sets than declared, a warning is raised.
+      </para>
+     </listitem>
+    </varlistentry>
+
     <varlistentry>
      <term><literal>TRANSFORM { FOR TYPE <replaceable 
class="parameter">type_name</replaceable> } [, ... ] }</literal></term>
 
diff --git a/doc/src/sgml/ref/declare.sgml b/doc/src/sgml/ref/declare.sgml
index 5712825314..a19198e6cb 100644
--- a/doc/src/sgml/ref/declare.sgml
+++ b/doc/src/sgml/ref/declare.sgml
@@ -32,7 +32,8 @@
  <refsynopsisdiv>
 <synopsis>
 DECLARE <replaceable class="parameter">name</replaceable> [ BINARY ] [ 
ASENSITIVE | INSENSITIVE ] [ [ NO ] SCROLL ]
-    CURSOR [ { WITH | WITHOUT } HOLD ] FOR <replaceable 
class="parameter">query</replaceable>
+    CURSOR [ { WITH | WITHOUT } HOLD ] [ { WITH | WITHOUT } RETURN ]
+    FOR <replaceable class="parameter">query</replaceable>
 </synopsis>
  </refsynopsisdiv>
 
@@ -138,6 +139,23 @@ <title>Parameters</title>
     </listitem>
    </varlistentry>
 
+   <varlistentry>
+    <term><literal>WITH RETURN</literal></term>
+    <term><literal>WITHOUT RETURN</literal></term>
+    <listitem>
+     <para>
+      This option is only valid for cursors defined inside a procedure or
+      <command>DO</command> block.  <literal>WITH RETURN</literal> specifies
+      that the cursor's result rows will be provided as a result set of the
+      procedure or code block invocation.  To accomplish that, the cursor must
+      be left open at the end of the procedure or code block.  If multiple
+      <literal>WITH RETURN</literal> cursors are declared, then their results
+      will be returned in the order they were created.  <literal>WITHOUT
+      RETURN</literal> is the default.
+     </para>
+    </listitem>
+   </varlistentry>
+
    <varlistentry>
     <term><replaceable class="parameter">query</replaceable></term>
     <listitem>
@@ -339,6 +357,21 @@ <title>Examples</title>
    See <xref linkend="sql-fetch"/> for more
    examples of cursor usage.
   </para>
+
+  <para>
+   This example shows how to return multiple result sets from a procedure:
+<programlisting>
+CREATE PROCEDURE test()
+LANGUAGE SQL
+AS $$
+DECLARE a CURSOR WITH RETURN FOR SELECT * FROM tbl1;
+DECLARE b CURSOR WITH RETURN FOR SELECT * FROM tbl2;
+$$;
+
+CALL test();
+</programlisting>
+   The results of the two cursors will be returned in order from this call.
+  </para>
  </refsect1>
 
  <refsect1>
diff --git a/src/backend/catalog/information_schema.sql 
b/src/backend/catalog/information_schema.sql
index 0555e9bc03..871a27b84b 100644
--- a/src/backend/catalog/information_schema.sql
+++ b/src/backend/catalog/information_schema.sql
@@ -1593,7 +1593,7 @@ CREATE VIEW routines AS
              CASE WHEN p.proisstrict THEN 'YES' ELSE 'NO' END END AS 
yes_or_no) AS is_null_call,
            CAST(null AS character_data) AS sql_path,
            CAST('YES' AS yes_or_no) AS schema_level_routine,
-           CAST(0 AS cardinal_number) AS max_dynamic_result_sets,
+           CAST(p.prodynres AS cardinal_number) AS max_dynamic_result_sets,
            CAST(null AS yes_or_no) AS is_user_defined_cast,
            CAST(null AS yes_or_no) AS is_implicitly_invocable,
            CAST(CASE WHEN p.prosecdef THEN 'DEFINER' ELSE 'INVOKER' END AS 
character_data) AS security_type,
diff --git a/src/backend/catalog/pg_aggregate.c 
b/src/backend/catalog/pg_aggregate.c
index ebc4454743..a633bb7501 100644
--- a/src/backend/catalog/pg_aggregate.c
+++ b/src/backend/catalog/pg_aggregate.c
@@ -640,7 +640,8 @@ AggregateCreate(const char *aggName,
                                                         PointerGetDatum(NULL), 
/* proconfig */
                                                         InvalidOid,    /* no 
prosupport */
                                                         1, /* procost */
-                                                        0);    /* prorows */
+                                                        0,     /* prorows */
+                                                        0);    /* prodynres */
        procOid = myself.objectId;
 
        /*
diff --git a/src/backend/catalog/pg_proc.c b/src/backend/catalog/pg_proc.c
index 14d552fe2d..620fb80a9c 100644
--- a/src/backend/catalog/pg_proc.c
+++ b/src/backend/catalog/pg_proc.c
@@ -95,7 +95,8 @@ ProcedureCreate(const char *procedureName,
                                Datum proconfig,
                                Oid prosupport,
                                float4 procost,
-                               float4 prorows)
+                               float4 prorows,
+                               int dynres)
 {
        Oid                     retval;
        int                     parameterCount;
@@ -314,6 +315,7 @@ ProcedureCreate(const char *procedureName,
        values[Anum_pg_proc_proretset - 1] = BoolGetDatum(returnsSet);
        values[Anum_pg_proc_provolatile - 1] = CharGetDatum(volatility);
        values[Anum_pg_proc_proparallel - 1] = CharGetDatum(parallel);
+       values[Anum_pg_proc_prodynres - 1] = Int32GetDatum(dynres);
        values[Anum_pg_proc_pronargs - 1] = UInt16GetDatum(parameterCount);
        values[Anum_pg_proc_pronargdefaults - 1] = 
UInt16GetDatum(list_length(parameterDefaults));
        values[Anum_pg_proc_prorettype - 1] = ObjectIdGetDatum(returnType);
diff --git a/src/backend/catalog/sql_features.txt 
b/src/backend/catalog/sql_features.txt
index 75a09f14e0..032bef862d 100644
--- a/src/backend/catalog/sql_features.txt
+++ b/src/backend/catalog/sql_features.txt
@@ -486,7 +486,7 @@ T433        Multiargument GROUPING function                 
YES
 T434   GROUP BY DISTINCT                       YES     
 T441   ABS and MOD functions                   YES     
 T461   Symmetric BETWEEN predicate                     YES     
-T471   Result sets return value                        NO      
+T471   Result sets return value                        NO      partially 
supported
 T472   DESCRIBE CURSOR                 NO      
 T491   LATERAL derived table                   YES     
 T495   Combined data change and retrieval                      NO      
different syntax
diff --git a/src/backend/commands/functioncmds.c 
b/src/backend/commands/functioncmds.c
index 69f66dfe7d..fe0a74c4d7 100644
--- a/src/backend/commands/functioncmds.c
+++ b/src/backend/commands/functioncmds.c
@@ -72,6 +72,7 @@
 #include "utils/guc.h"
 #include "utils/lsyscache.h"
 #include "utils/memutils.h"
+#include "utils/portal.h"
 #include "utils/rel.h"
 #include "utils/snapmgr.h"
 #include "utils/syscache.h"
@@ -513,7 +514,8 @@ compute_common_attribute(ParseState *pstate,
                                                 DefElem **cost_item,
                                                 DefElem **rows_item,
                                                 DefElem **support_item,
-                                                DefElem **parallel_item)
+                                                DefElem **parallel_item,
+                                                DefElem **dynres_item)
 {
        if (strcmp(defel->defname, "volatility") == 0)
        {
@@ -589,12 +591,28 @@ compute_common_attribute(ParseState *pstate,
 
                *parallel_item = defel;
        }
+       else if (strcmp(defel->defname, "dynamic_result_sets") == 0)
+       {
+               if (!is_procedure)
+                       goto function_error;
+               if (*dynres_item)
+                       errorConflictingDefElem(defel, pstate);
+
+               *dynres_item = defel;
+       }
        else
                return false;
 
        /* Recognized an option */
        return true;
 
+function_error:
+       ereport(ERROR,
+                       (errcode(ERRCODE_INVALID_FUNCTION_DEFINITION),
+                        errmsg("invalid attribute in function definition"),
+                        parser_errposition(pstate, defel->location)));
+       return false;
+
 procedure_error:
        ereport(ERROR,
                        (errcode(ERRCODE_INVALID_FUNCTION_DEFINITION),
@@ -731,7 +749,8 @@ compute_function_attributes(ParseState *pstate,
                                                        float4 *procost,
                                                        float4 *prorows,
                                                        Oid *prosupport,
-                                                       char *parallel_p)
+                                                       char *parallel_p,
+                                                       int *dynres_p)
 {
        ListCell   *option;
        DefElem    *as_item = NULL;
@@ -747,6 +766,7 @@ compute_function_attributes(ParseState *pstate,
        DefElem    *rows_item = NULL;
        DefElem    *support_item = NULL;
        DefElem    *parallel_item = NULL;
+       DefElem    *dynres_item = NULL;
 
        foreach(option, options)
        {
@@ -792,7 +812,8 @@ compute_function_attributes(ParseState *pstate,
                                                                                
  &cost_item,
                                                                                
  &rows_item,
                                                                                
  &support_item,
-                                                                               
  &parallel_item))
+                                                                               
  &parallel_item,
+                                                                               
  &dynres_item))
                {
                        /* recognized common option */
                        continue;
@@ -840,6 +861,11 @@ compute_function_attributes(ParseState *pstate,
                *prosupport = interpret_func_support(support_item);
        if (parallel_item)
                *parallel_p = interpret_func_parallel(parallel_item);
+       if (dynres_item)
+       {
+               *dynres_p = intVal(dynres_item->arg);
+               Assert(*dynres_p >= 0); /* enforced by parser */
+       }
 }
 
 
@@ -1051,6 +1077,7 @@ CreateFunction(ParseState *pstate, CreateFunctionStmt 
*stmt)
        Form_pg_language languageStruct;
        List       *as_clause;
        char            parallel;
+       int                     dynres;
 
        /* Convert list of names to a name and namespace */
        namespaceId = QualifiedNameGetCreationNamespace(stmt->funcname,
@@ -1075,6 +1102,7 @@ CreateFunction(ParseState *pstate, CreateFunctionStmt 
*stmt)
        prorows = -1;                           /* indicates not set */
        prosupport = InvalidOid;
        parallel = PROPARALLEL_UNSAFE;
+       dynres = 0;
 
        /* Extract non-default attributes from stmt->options list */
        compute_function_attributes(pstate,
@@ -1084,7 +1112,7 @@ CreateFunction(ParseState *pstate, CreateFunctionStmt 
*stmt)
                                                                &isWindowFunc, 
&volatility,
                                                                &isStrict, 
&security, &isLeakProof,
                                                                &proconfig, 
&procost, &prorows,
-                                                               &prosupport, 
&parallel);
+                                                               &prosupport, 
&parallel, &dynres);
 
        if (!language)
        {
@@ -1285,7 +1313,8 @@ CreateFunction(ParseState *pstate, CreateFunctionStmt 
*stmt)
                                                   PointerGetDatum(proconfig),
                                                   prosupport,
                                                   procost,
-                                                  prorows);
+                                                  prorows,
+                                                  dynres);
 }
 
 /*
@@ -1362,6 +1391,7 @@ AlterFunction(ParseState *pstate, AlterFunctionStmt *stmt)
        DefElem    *rows_item = NULL;
        DefElem    *support_item = NULL;
        DefElem    *parallel_item = NULL;
+       DefElem    *dynres_item = NULL;
        ObjectAddress address;
 
        rel = table_open(ProcedureRelationId, RowExclusiveLock);
@@ -1405,7 +1435,8 @@ AlterFunction(ParseState *pstate, AlterFunctionStmt *stmt)
                                                                         
&cost_item,
                                                                         
&rows_item,
                                                                         
&support_item,
-                                                                        
&parallel_item) == false)
+                                                                        
&parallel_item,
+                                                                        
&dynres_item) == false)
                        elog(ERROR, "option \"%s\" not recognized", 
defel->defname);
        }
 
@@ -1467,6 +1498,8 @@ AlterFunction(ParseState *pstate, AlterFunctionStmt *stmt)
        }
        if (parallel_item)
                procForm->proparallel = interpret_func_parallel(parallel_item);
+       if (dynres_item)
+               procForm->prodynres = intVal(dynres_item->arg);
        if (set_items)
        {
                Datum           datum;
@@ -2044,6 +2077,17 @@ IsThereFunctionInNamespace(const char *proname, int 
pronargs,
                                                get_namespace_name(nspOid))));
 }
 
+static List *procedure_stack;
+
+Oid
+CurrentProcedure(void)
+{
+       if (!procedure_stack)
+               return InvalidOid;
+       else
+               return llast_oid(procedure_stack);
+}
+
 /*
  * ExecuteDoStmt
  *             Execute inline procedural-language code
@@ -2140,8 +2184,19 @@ ExecuteDoStmt(ParseState *pstate, DoStmt *stmt, bool 
atomic)
 
        ReleaseSysCache(languageTuple);
 
-       /* execute the inline handler */
-       OidFunctionCall1(laninline, PointerGetDatum(codeblock));
+       procedure_stack = lappend_oid(procedure_stack, InvalidOid);
+       PG_TRY();
+       {
+               /* execute the inline handler */
+               OidFunctionCall1(laninline, PointerGetDatum(codeblock));
+       }
+       PG_FINALLY();
+       {
+               procedure_stack = list_delete_last(procedure_stack);
+       }
+       PG_END_TRY();
+
+       CloseOtherReturnableCursors(InvalidOid);
 }
 
 /*
@@ -2183,6 +2238,7 @@ ExecuteCallStmt(CallStmt *stmt, ParamListInfo params, 
bool atomic, DestReceiver
        AclResult       aclresult;
        FmgrInfo        flinfo;
        CallContext *callcontext;
+       int                     prodynres;
        EState     *estate;
        ExprContext *econtext;
        HeapTuple       tp;
@@ -2223,6 +2279,8 @@ ExecuteCallStmt(CallStmt *stmt, ParamListInfo params, 
bool atomic, DestReceiver
        if (((Form_pg_proc) GETSTRUCT(tp))->prosecdef)
                callcontext->atomic = true;
 
+       prodynres = ((Form_pg_proc) GETSTRUCT(tp))->prodynres;
+
        ReleaseSysCache(tp);
 
        /* safety check; see ExecInitFunc() */
@@ -2283,7 +2341,18 @@ ExecuteCallStmt(CallStmt *stmt, ParamListInfo params, 
bool atomic, DestReceiver
 
        /* Here we actually call the procedure */
        pgstat_init_function_usage(fcinfo, &fcusage);
-       retval = FunctionCallInvoke(fcinfo);
+
+       procedure_stack = lappend_oid(procedure_stack, fexpr->funcid);
+       PG_TRY();
+       {
+               retval = FunctionCallInvoke(fcinfo);
+       }
+       PG_FINALLY();
+       {
+               procedure_stack = list_delete_last(procedure_stack);
+       }
+       PG_END_TRY();
+
        pgstat_end_function_usage(&fcusage, true);
 
        /* Handle the procedure's outputs */
@@ -2344,6 +2413,13 @@ ExecuteCallStmt(CallStmt *stmt, ParamListInfo params, 
bool atomic, DestReceiver
                         fexpr->funcresulttype);
 
        FreeExecutorState(estate);
+
+       CloseOtherReturnableCursors(fexpr->funcid);
+
+       if (list_length(GetReturnableCursors()) > prodynres)
+               ereport(WARNING,
+                               
errcode(ERRCODE_WARNING_ATTEMPT_TO_RETURN_TOO_MANY_RESULT_SETS),
+                               errmsg("attempt to return too many result 
sets"));
 }
 
 /*
diff --git a/src/backend/commands/portalcmds.c 
b/src/backend/commands/portalcmds.c
index 8a3cf98cce..e73f7bfb22 100644
--- a/src/backend/commands/portalcmds.c
+++ b/src/backend/commands/portalcmds.c
@@ -24,6 +24,7 @@
 #include <limits.h>
 
 #include "access/xact.h"
+#include "commands/defrem.h"
 #include "commands/portalcmds.h"
 #include "executor/executor.h"
 #include "executor/tstoreReceiver.h"
@@ -140,6 +141,28 @@ PerformCursorOpen(ParseState *pstate, DeclareCursorStmt 
*cstmt, ParamListInfo pa
                        portal->cursorOptions |= CURSOR_OPT_NO_SCROLL;
        }
 
+       /*
+        * For returnable cursors, remember the currently active procedure, as
+        * well as the command ID, so we can sort by creation order later.  If
+        * there is no procedure active, the cursor is marked as WITHOUT RETURN.
+        * (This is not an error, per SQL standard, subclause "Effect of 
opening a
+        * cursor".)
+        */
+       if (portal->cursorOptions & CURSOR_OPT_RETURN)
+       {
+               Oid                     procId = CurrentProcedure();
+
+               if (procId)
+               {
+                       portal->procId = procId;
+                       portal->createCid = GetCurrentCommandId(true);
+               }
+               else
+               {
+                       portal->cursorOptions &= ~CURSOR_OPT_RETURN;
+               }
+       }
+
        /*
         * Start execution, inserting parameters if any.
         */
diff --git a/src/backend/commands/typecmds.c b/src/backend/commands/typecmds.c
index 04bddaef81..1e40fcedd3 100644
--- a/src/backend/commands/typecmds.c
+++ b/src/backend/commands/typecmds.c
@@ -1777,7 +1777,8 @@ makeRangeConstructors(const char *name, Oid namespace,
                                                                 
PointerGetDatum(NULL), /* proconfig */
                                                                 InvalidOid,    
/* prosupport */
                                                                 1.0,   /* 
procost */
-                                                                0.0);  /* 
prorows */
+                                                                0.0,   /* 
prorows */
+                                                                0);    /* 
prodynres */
 
                /*
                 * Make the constructors internally-dependent on the range type 
so
@@ -1842,7 +1843,8 @@ makeMultirangeConstructors(const char *name, Oid 
namespace,
                                                         PointerGetDatum(NULL), 
/* proconfig */
                                                         InvalidOid,    /* 
prosupport */
                                                         1.0,   /* procost */
-                                                        0.0);  /* prorows */
+                                                        0.0,   /* prorows */
+                                                        0);    /* prodynres */
 
        /*
         * Make the constructor internally-dependent on the multirange type so
@@ -1886,7 +1888,8 @@ makeMultirangeConstructors(const char *name, Oid 
namespace,
                                                         PointerGetDatum(NULL), 
/* proconfig */
                                                         InvalidOid,    /* 
prosupport */
                                                         1.0,   /* procost */
-                                                        0.0);  /* prorows */
+                                                        0.0,   /* prorows */
+                                                        0);    /* prodynres */
        /* ditto */
        recordDependencyOn(&myself, &referenced, DEPENDENCY_INTERNAL);
        pfree(argtypes);
@@ -1924,7 +1927,8 @@ makeMultirangeConstructors(const char *name, Oid 
namespace,
                                                         PointerGetDatum(NULL), 
/* proconfig */
                                                         InvalidOid,    /* 
prosupport */
                                                         1.0,   /* procost */
-                                                        0.0);  /* prorows */
+                                                        0.0,   /* prorows */
+                                                        0);    /* prodynres */
        /* ditto */
        recordDependencyOn(&myself, &referenced, DEPENDENCY_INTERNAL);
        pfree(argtypes);
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index a0138382a1..8312fbf2c6 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -688,7 +688,7 @@ static Node *makeRecursiveViewSelect(char *relname, List 
*aliases, Node *query);
        DATA_P DATABASE DAY_P DEALLOCATE DEC DECIMAL_P DECLARE DEFAULT DEFAULTS
        DEFERRABLE DEFERRED DEFINER DELETE_P DELIMITER DELIMITERS DEPENDS DEPTH 
DESC
        DETACH DICTIONARY DISABLE_P DISCARD DISTINCT DO DOCUMENT_P DOMAIN_P
-       DOUBLE_P DROP
+       DOUBLE_P DROP DYNAMIC
 
        EACH ELSE ENABLE_P ENCODING ENCRYPTED END_P ENUM_P ESCAPE EVENT EXCEPT
        EXCLUDE EXCLUDING EXCLUSIVE EXECUTE EXISTS EXPLAIN EXPRESSION
@@ -735,7 +735,7 @@ static Node *makeRecursiveViewSelect(char *relname, List 
*aliases, Node *query);
 
        RANGE READ REAL REASSIGN RECHECK RECURSIVE REF_P REFERENCES REFERENCING
        REFRESH REINDEX RELATIVE_P RELEASE RENAME REPEATABLE REPLACE REPLICA
-       RESET RESTART RESTRICT RETURN RETURNING RETURNS REVOKE RIGHT ROLE 
ROLLBACK ROLLUP
+       RESET RESTART RESTRICT RESULT RETURN RETURNING RETURNS REVOKE RIGHT 
ROLE ROLLBACK ROLLUP
        ROUTINE ROUTINES ROW ROWS RULE
 
        SAVEPOINT SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT 
SEQUENCE SEQUENCES
@@ -8532,6 +8532,10 @@ common_func_opt_item:
                                {
                                        $$ = makeDefElem("parallel", (Node *) 
makeString($2), @1);
                                }
+                       | DYNAMIC RESULT SETS Iconst
+                               {
+                                       $$ = makeDefElem("dynamic_result_sets", 
(Node *)makeInteger($4), @1);
+                               }
                ;
 
 createfunc_opt_item:
@@ -12421,6 +12425,12 @@ cursor_options: /*EMPTY*/                              
        { $$ = 0; }
 opt_hold: /* EMPTY */                                          { $$ = 0; }
                        | WITH HOLD                                             
{ $$ = CURSOR_OPT_HOLD; }
                        | WITHOUT HOLD                                  { $$ = 
0; }
+                       | WITH HOLD WITH RETURN                 { $$ = 
CURSOR_OPT_HOLD | CURSOR_OPT_RETURN; }
+                       | WITHOUT HOLD WITH RETURN              { $$ = 
CURSOR_OPT_RETURN; }
+                       | WITH HOLD WITHOUT RETURN              { $$ = 
CURSOR_OPT_HOLD; }
+                       | WITHOUT HOLD WITHOUT RETURN   { $$ = 0; }
+                       | WITH RETURN                                   { $$ = 
CURSOR_OPT_RETURN; }
+                       | WITHOUT RETURN                                { $$ = 
0; }
                ;
 
 /*****************************************************************************
@@ -16787,6 +16797,7 @@ unreserved_keyword:
                        | DOMAIN_P
                        | DOUBLE_P
                        | DROP
+                       | DYNAMIC
                        | EACH
                        | ENABLE_P
                        | ENCODING
@@ -16932,6 +16943,7 @@ unreserved_keyword:
                        | RESET
                        | RESTART
                        | RESTRICT
+                       | RESULT
                        | RETURN
                        | RETURNS
                        | REVOKE
@@ -17332,6 +17344,7 @@ bare_label_keyword:
                        | DOMAIN_P
                        | DOUBLE_P
                        | DROP
+                       | DYNAMIC
                        | EACH
                        | ELSE
                        | ENABLE_P
@@ -17519,6 +17532,7 @@ bare_label_keyword:
                        | RESET
                        | RESTART
                        | RESTRICT
+                       | RESULT
                        | RETURN
                        | RETURNS
                        | REVOKE
diff --git a/src/backend/tcop/postgres.c b/src/backend/tcop/postgres.c
index cab709b07b..98ac9aa012 100644
--- a/src/backend/tcop/postgres.c
+++ b/src/backend/tcop/postgres.c
@@ -32,6 +32,7 @@
 #include "access/xact.h"
 #include "catalog/pg_type.h"
 #include "commands/async.h"
+#include "commands/defrem.h"
 #include "commands/prepare.h"
 #include "common/pg_prng.h"
 #include "jit/jit.h"
@@ -1073,6 +1074,7 @@ exec_simple_query(const char *query_string)
                int16           format;
                const char *cmdtagname;
                size_t          cmdtaglen;
+               ListCell   *lc;
 
                pgstat_report_query_id(0, true);
 
@@ -1235,7 +1237,7 @@ exec_simple_query(const char *query_string)
                MemoryContextSwitchTo(oldcontext);
 
                /*
-                * Run the portal to completion, and then drop it (and the 
receiver).
+                * Run the portal to completion, and then drop it.
                 */
                (void) PortalRun(portal,
                                                 FETCH_ALL,
@@ -1245,10 +1247,34 @@ exec_simple_query(const char *query_string)
                                                 receiver,
                                                 &qc);
 
-               receiver->rDestroy(receiver);
-
                PortalDrop(portal, false);
 
+               /*
+                * Run portals for dynamic result sets.
+                */
+               foreach (lc, GetReturnableCursors())
+               {
+                       Portal          dynportal = lfirst(lc);
+
+                       if (dest == DestRemote)
+                               SetRemoteDestReceiverParams(receiver, 
dynportal);
+
+                       PortalRun(dynportal,
+                                         FETCH_ALL,
+                                         true,
+                                         true,
+                                         receiver,
+                                         receiver,
+                                         NULL);
+
+                       PortalDrop(dynportal, false);
+               }
+
+               /*
+                * Drop the receiver.
+                */
+               receiver->rDestroy(receiver);
+
                if (lnext(parsetree_list, parsetree_item) == NULL)
                {
                        /*
@@ -2200,6 +2226,11 @@ exec_execute_message(const char *portal_name, long 
max_rows)
                                                  receiver,
                                                  &qc);
 
+       if (GetReturnableCursors())
+               ereport(ERROR,
+                               errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+                               errmsg("dynamic result sets are not yet 
supported in extended query protocol"));
+
        receiver->rDestroy(receiver);
 
        /* Done executing; remove the params error callback */
diff --git a/src/backend/utils/errcodes.txt b/src/backend/utils/errcodes.txt
index 3d244af130..9b94a5fa92 100644
--- a/src/backend/utils/errcodes.txt
+++ b/src/backend/utils/errcodes.txt
@@ -83,6 +83,7 @@ Section: Class 01 - Warning
 # do not use this class for failure conditions
 01000    W    ERRCODE_WARNING                                                
warning
 0100C    W    ERRCODE_WARNING_DYNAMIC_RESULT_SETS_RETURNED                   
dynamic_result_sets_returned
+0100E    W    ERRCODE_WARNING_ATTEMPT_TO_RETURN_TOO_MANY_RESULT_SETS         
attempt_to_return_too_many_result_sets
 01008    W    ERRCODE_WARNING_IMPLICIT_ZERO_BIT_PADDING                      
implicit_zero_bit_padding
 01003    W    ERRCODE_WARNING_NULL_VALUE_ELIMINATED_IN_SET_FUNCTION          
null_value_eliminated_in_set_function
 01007    W    ERRCODE_WARNING_PRIVILEGE_NOT_GRANTED                          
privilege_not_granted
diff --git a/src/backend/utils/mmgr/portalmem.c 
b/src/backend/utils/mmgr/portalmem.c
index 06dfa85f04..f29a6eabf8 100644
--- a/src/backend/utils/mmgr/portalmem.c
+++ b/src/backend/utils/mmgr/portalmem.c
@@ -1289,3 +1289,51 @@ ForgetPortalSnapshots(void)
                elog(ERROR, "portal snapshots (%d) did not account for all 
active snapshots (%d)",
                         numPortalSnaps, numActiveSnaps);
 }
+
+static int
+cmp_portals_by_creation(const ListCell *a, const ListCell *b)
+{
+       Portal          pa = lfirst(a);
+       Portal          pb = lfirst(b);
+
+       return pa->createCid - pb->createCid;
+}
+
+List *
+GetReturnableCursors(void)
+{
+       List       *ret = NIL;
+       HASH_SEQ_STATUS status;
+       PortalHashEnt *hentry;
+
+       hash_seq_init(&status, PortalHashTable);
+
+       while ((hentry = (PortalHashEnt *) hash_seq_search(&status)) != NULL)
+       {
+               Portal          portal = hentry->portal;
+
+               if (portal->cursorOptions & CURSOR_OPT_RETURN)
+                       ret = lappend(ret, portal);
+       }
+
+       list_sort(ret, cmp_portals_by_creation);
+
+       return ret;
+}
+
+void
+CloseOtherReturnableCursors(Oid procid)
+{
+       HASH_SEQ_STATUS status;
+       PortalHashEnt *hentry;
+
+       hash_seq_init(&status, PortalHashTable);
+
+       while ((hentry = (PortalHashEnt *) hash_seq_search(&status)) != NULL)
+       {
+               Portal          portal = hentry->portal;
+
+               if (portal->cursorOptions & CURSOR_OPT_RETURN && portal->procId 
!= procid)
+                       PortalDrop(portal, false);
+       }
+}
diff --git a/src/bin/pg_dump/pg_dump.c b/src/bin/pg_dump/pg_dump.c
index cc424fd3b2..1bc4aacedb 100644
--- a/src/bin/pg_dump/pg_dump.c
+++ b/src/bin/pg_dump/pg_dump.c
@@ -11641,6 +11641,7 @@ dumpFunc(Archive *fout, const FuncInfo *finfo)
        char       *prorows;
        char       *prosupport;
        char       *proparallel;
+       int                     prodynres;
        char       *lanname;
        char      **configitems = NULL;
        int                     nconfigitems = 0;
@@ -11708,10 +11709,17 @@ dumpFunc(Archive *fout, const FuncInfo *finfo)
 
                if (fout->remoteVersion >= 140000)
                        appendPQExpBufferStr(query,
-                                                                
"pg_get_function_sqlbody(p.oid) AS prosqlbody\n");
+                                                                
"pg_get_function_sqlbody(p.oid) AS prosqlbody,\n");
                else
                        appendPQExpBufferStr(query,
-                                                                "NULL AS 
prosqlbody\n");
+                                                                "NULL AS 
prosqlbody,\n");
+
+               if (fout->remoteVersion >= 160000)
+                       appendPQExpBufferStr(query,
+                                                                "prodynres\n");
+               else
+                       appendPQExpBufferStr(query,
+                                                                "0 AS 
prodynres\n");
 
                appendPQExpBufferStr(query,
                                                         "FROM 
pg_catalog.pg_proc p, pg_catalog.pg_language l\n"
@@ -11756,6 +11764,7 @@ dumpFunc(Archive *fout, const FuncInfo *finfo)
        prorows = PQgetvalue(res, 0, PQfnumber(res, "prorows"));
        prosupport = PQgetvalue(res, 0, PQfnumber(res, "prosupport"));
        proparallel = PQgetvalue(res, 0, PQfnumber(res, "proparallel"));
+       prodynres = atoi(PQgetvalue(res, 0, PQfnumber(res, "prodynres")));
        lanname = PQgetvalue(res, 0, PQfnumber(res, "lanname"));
 
        /*
@@ -11874,6 +11883,9 @@ dumpFunc(Archive *fout, const FuncInfo *finfo)
        if (proisstrict[0] == 't')
                appendPQExpBufferStr(q, " STRICT");
 
+       if (prodynres > 0)
+               appendPQExpBuffer(q, " DYNAMIC RESULT SETS %d", prodynres);
+
        if (prosecdef[0] == 't')
                appendPQExpBufferStr(q, " SECURITY DEFINER");
 
diff --git a/src/include/catalog/pg_proc.h b/src/include/catalog/pg_proc.h
index e7abe0b497..f4ef8f0ece 100644
--- a/src/include/catalog/pg_proc.h
+++ b/src/include/catalog/pg_proc.h
@@ -76,6 +76,9 @@ CATALOG(pg_proc,1255,ProcedureRelationId) BKI_BOOTSTRAP 
BKI_ROWTYPE_OID(81,Proce
        /* see PROPARALLEL_ categories below */
        char            proparallel BKI_DEFAULT(s);
 
+       /* maximum number of dynamic result sets */
+       int32           prodynres BKI_DEFAULT(0);
+
        /* number of arguments */
        /* Note: need not be given in pg_proc.dat; genbki.pl will compute it */
        int16           pronargs;
@@ -211,7 +214,8 @@ extern ObjectAddress ProcedureCreate(const char 
*procedureName,
                                                                         Datum 
proconfig,
                                                                         Oid 
prosupport,
                                                                         float4 
procost,
-                                                                        float4 
prorows);
+                                                                        float4 
prorows,
+                                                                        int 
dynres);
 
 extern bool function_parse_error_transpose(const char *prosrc);
 
diff --git a/src/include/commands/defrem.h b/src/include/commands/defrem.h
index 4f7f87fc62..fcfe8df78e 100644
--- a/src/include/commands/defrem.h
+++ b/src/include/commands/defrem.h
@@ -57,6 +57,7 @@ extern ObjectAddress CreateTransform(CreateTransformStmt 
*stmt);
 extern void IsThereFunctionInNamespace(const char *proname, int pronargs,
                                                                           
oidvector *proargtypes, Oid nspOid);
 extern void ExecuteDoStmt(ParseState *pstate, DoStmt *stmt, bool atomic);
+extern Oid     CurrentProcedure(void);
 extern void ExecuteCallStmt(CallStmt *stmt, ParamListInfo params, bool atomic, 
DestReceiver *dest);
 extern TupleDesc CallStmtResultDesc(CallStmt *stmt);
 extern Oid     get_transform_oid(Oid type_id, Oid lang_id, bool missing_ok);
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index f7d7f10f7d..acae7da708 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -3010,6 +3010,7 @@ typedef struct SecLabelStmt
 #define CURSOR_OPT_INSENSITIVE 0x0008  /* INSENSITIVE */
 #define CURSOR_OPT_ASENSITIVE  0x0010  /* ASENSITIVE */
 #define CURSOR_OPT_HOLD                        0x0020  /* WITH HOLD */
+#define CURSOR_OPT_RETURN              0x0040  /* WITH RETURN */
 /* these planner-control flags do not correspond to any SQL grammar: */
 #define CURSOR_OPT_FAST_PLAN   0x0100  /* prefer fast-start plan */
 #define CURSOR_OPT_GENERIC_PLAN 0x0200 /* force use of generic plan */
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index bb36213e6f..60457d21f7 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -144,6 +144,7 @@ PG_KEYWORD("document", DOCUMENT_P, UNRESERVED_KEYWORD, 
BARE_LABEL)
 PG_KEYWORD("domain", DOMAIN_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("double", DOUBLE_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("drop", DROP, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("dynamic", DYNAMIC, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("each", EACH, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("else", ELSE, RESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("enable", ENABLE_P, UNRESERVED_KEYWORD, BARE_LABEL)
@@ -353,6 +354,7 @@ PG_KEYWORD("replica", REPLICA, UNRESERVED_KEYWORD, 
BARE_LABEL)
 PG_KEYWORD("reset", RESET, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("restart", RESTART, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("restrict", RESTRICT, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("result", RESULT, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("return", RETURN, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("returning", RETURNING, RESERVED_KEYWORD, AS_LABEL)
 PG_KEYWORD("returns", RETURNS, UNRESERVED_KEYWORD, BARE_LABEL)
diff --git a/src/include/utils/portal.h b/src/include/utils/portal.h
index aa08b1e0fc..6f04362dfe 100644
--- a/src/include/utils/portal.h
+++ b/src/include/utils/portal.h
@@ -132,6 +132,16 @@ typedef struct PortalData
        SubTransactionId activeSubid;   /* the last subxact with activity */
        int                     createLevel;    /* creating subxact's nesting 
level */
 
+       /*
+        * Procedure that created this portal.  Used for returnable cursors.
+        */
+       Oid                             procId;
+       /*
+        * Command ID where the portal was created.  Used for sorting returnable
+        * cursors into creation order.
+        */
+       CommandId               createCid;
+
        /* The query or queries the portal will execute */
        const char *sourceText;         /* text of query (as of 8.4, never 
NULL) */
        CommandTag      commandTag;             /* command tag for original 
query */
@@ -248,5 +258,7 @@ extern void PortalHashTableDeleteAll(void);
 extern bool ThereAreNoReadyPortals(void);
 extern void HoldPinnedPortals(void);
 extern void ForgetPortalSnapshots(void);
+extern List *GetReturnableCursors(void);
+extern void CloseOtherReturnableCursors(Oid procid);
 
 #endif                                                 /* PORTAL_H */
diff --git a/src/pl/plpgsql/src/Makefile b/src/pl/plpgsql/src/Makefile
index f7eb42d54f..0b9686fbff 100644
--- a/src/pl/plpgsql/src/Makefile
+++ b/src/pl/plpgsql/src/Makefile
@@ -34,7 +34,7 @@ REGRESS_OPTS = --dbname=$(PL_TESTDB)
 
 REGRESS = plpgsql_array plpgsql_call plpgsql_control plpgsql_copy 
plpgsql_domain \
        plpgsql_record plpgsql_cache plpgsql_simple plpgsql_transaction \
-       plpgsql_trap plpgsql_trigger plpgsql_varprops
+       plpgsql_trap plpgsql_trigger plpgsql_varprops plpgsql_with_return
 
 # where to find gen_keywordlist.pl and subsidiary files
 TOOLSDIR = $(top_srcdir)/src/tools
diff --git a/src/pl/plpgsql/src/expected/plpgsql_with_return.out 
b/src/pl/plpgsql/src/expected/plpgsql_with_return.out
new file mode 100644
index 0000000000..2f6b034e5e
--- /dev/null
+++ b/src/pl/plpgsql/src/expected/plpgsql_with_return.out
@@ -0,0 +1,105 @@
+CREATE TABLE drs_test1 (a int);
+INSERT INTO drs_test1 VALUES (1), (2), (3);
+CREATE TABLE drs_test2 (x text, y text);
+INSERT INTO drs_test2 VALUES ('abc', 'def'), ('foo', 'bar');
+CREATE PROCEDURE pdrstest1(x int)
+LANGUAGE plpgsql
+DYNAMIC RESULT SETS 2
+AS $$
+DECLARE
+  c1 CURSOR WITH RETURN (y int) FOR SELECT a * y AS ay FROM drs_test1;
+  c2 CURSOR WITH RETURN FOR SELECT * FROM drs_test2;
+BEGIN
+  OPEN c1(x);
+  IF x > 1 THEN
+    OPEN c2;
+  END IF;
+END;
+$$;
+CALL pdrstest1(1);
+ ay 
+----
+  1
+  2
+  3
+(3 rows)
+
+CALL pdrstest1(2);
+ ay 
+----
+  2
+  4
+  6
+(3 rows)
+
+  x  |  y  
+-----+-----
+ abc | def
+ foo | bar
+(2 rows)
+
+DO $$
+DECLARE
+  c1 CURSOR WITH RETURN (y int) FOR SELECT a * y AS ay FROM drs_test1;
+  c2 CURSOR WITH RETURN FOR SELECT * FROM drs_test2;
+BEGIN
+  OPEN c1(1);
+  OPEN c2;
+END;
+$$;
+ ay 
+----
+  1
+  2
+  3
+(3 rows)
+
+  x  |  y  
+-----+-----
+ abc | def
+ foo | bar
+(2 rows)
+
+-- (The result sets of the called procedure are not returned.)
+DO $$
+BEGIN
+  CALL pdrstest1(1);
+END;
+$$;
+CREATE PROCEDURE pdrstest2(x int)
+LANGUAGE plpgsql
+DYNAMIC RESULT SETS 2
+AS $$
+DECLARE
+  c1 refcursor;
+  c2 refcursor;
+BEGIN
+  OPEN c1 WITH RETURN FOR SELECT a * x AS ax FROM drs_test1;
+  IF x > 1 THEN
+    OPEN c2 SCROLL WITH RETURN FOR SELECT * FROM drs_test2;
+  END IF;
+END;
+$$;
+CALL pdrstest2(1);
+ ax 
+----
+  1
+  2
+  3
+(3 rows)
+
+CALL pdrstest2(2);
+ ax 
+----
+  2
+  4
+  6
+(3 rows)
+
+  x  |  y  
+-----+-----
+ abc | def
+ foo | bar
+(2 rows)
+
+DROP TABLE drs_test1, drs_test2;
diff --git a/src/pl/plpgsql/src/meson.build b/src/pl/plpgsql/src/meson.build
index e185a87024..b6fc35e23f 100644
--- a/src/pl/plpgsql/src/meson.build
+++ b/src/pl/plpgsql/src/meson.build
@@ -86,6 +86,7 @@ tests += {
       'plpgsql_trap',
       'plpgsql_trigger',
       'plpgsql_varprops',
+      'plpgsql_with_return',
     ],
   },
 }
diff --git a/src/pl/plpgsql/src/pl_exec.c b/src/pl/plpgsql/src/pl_exec.c
index ffd6d2e3bc..ea11144f6d 100644
--- a/src/pl/plpgsql/src/pl_exec.c
+++ b/src/pl/plpgsql/src/pl_exec.c
@@ -4776,6 +4776,12 @@ exec_stmt_open(PLpgSQL_execstate *estate, 
PLpgSQL_stmt_open *stmt)
                elog(ERROR, "could not open cursor: %s",
                         SPI_result_code_string(SPI_result));
 
+       if (portal->cursorOptions & CURSOR_OPT_RETURN)
+       {
+               portal->procId = estate->func->fn_oid;
+               portal->createCid = GetCurrentCommandId(true);
+       }
+
        /*
         * If cursor variable was NULL, store the generated portal name in it,
         * after verifying it's okay to assign to.
diff --git a/src/pl/plpgsql/src/pl_gram.y b/src/pl/plpgsql/src/pl_gram.y
index edeb72c380..bff1557005 100644
--- a/src/pl/plpgsql/src/pl_gram.y
+++ b/src/pl/plpgsql/src/pl_gram.y
@@ -212,7 +212,7 @@ static      void                    
check_raise_parameters(PLpgSQL_stmt_raise *stmt);
 %type <datum>  getdiag_target
 %type <ival>   getdiag_item
 
-%type <ival>   opt_scrollable
+%type <ival>   opt_scrollable opt_with_return
 %type <fetch>  opt_fetch_direction
 
 %type <ival>   opt_transaction_chain
@@ -352,6 +352,8 @@ static      void                    
check_raise_parameters(PLpgSQL_stmt_raise *stmt);
 %token <keyword>       K_WARNING
 %token <keyword>       K_WHEN
 %token <keyword>       K_WHILE
+%token <keyword>       K_WITH
+%token <keyword>       K_WITHOUT
 
 %%
 
@@ -529,7 +531,7 @@ decl_statement      : decl_varname decl_const decl_datatype 
decl_collate decl_notnull
                                                plpgsql_ns_additem($4->itemtype,
                                                                                
   $4->itemno, $1.name);
                                        }
-                               | decl_varname opt_scrollable K_CURSOR
+                               | decl_varname opt_scrollable K_CURSOR 
opt_with_return
                                        { plpgsql_ns_push($1.name, 
PLPGSQL_LABEL_OTHER); }
                                  decl_cursor_args decl_is_for decl_cursor_query
                                        {
@@ -546,12 +548,12 @@ decl_statement    : decl_varname decl_const decl_datatype 
decl_collate decl_notnull
                                                                                
                                                                  NULL),
                                                                                
                   true);
 
-                                               new->cursor_explicit_expr = $7;
-                                               if ($5 == NULL)
+                                               new->cursor_explicit_expr = $8;
+                                               if ($6 == NULL)
                                                        
new->cursor_explicit_argrow = -1;
                                                else
-                                                       
new->cursor_explicit_argrow = $5->dno;
-                                               new->cursor_options = 
CURSOR_OPT_FAST_PLAN | $2;
+                                                       
new->cursor_explicit_argrow = $6->dno;
+                                               new->cursor_options = 
CURSOR_OPT_FAST_PLAN | $2 | $4;
                                        }
                                ;
 
@@ -569,6 +571,20 @@ opt_scrollable :
                                        }
                                ;
 
+opt_with_return :
+                                       {
+                                               $$ = 0;
+                                       }
+                               | K_WITH K_RETURN
+                                       {
+                                               $$ = CURSOR_OPT_RETURN;
+                                       }
+                               | K_WITHOUT K_RETURN
+                                       {
+                                               $$ = 0;
+                                       }
+                               ;
+
 decl_cursor_query :
                                        {
                                                $$ = read_sql_stmt();
@@ -1976,6 +1992,10 @@ stmt_execsql     : K_IMPORT
                                        {
                                                $$ = make_execsql_stmt(K_MERGE, 
@1);
                                        }
+                               | K_WITH
+                                       {
+                                               $$ = make_execsql_stmt(K_WITH, 
@1);
+                                       }
                                | T_WORD
                                        {
                                                int                     tok;
@@ -2098,6 +2118,30 @@ stmt_open                : K_OPEN cursor_variable
                                                                tok = yylex();
                                                        }
 
+                                                       /* same for 
opt_with_return */
+                                                       if (tok_is_keyword(tok, 
&yylval,
+                                                                               
           K_WITH, "with"))
+                                                       {
+                                                               tok = yylex();
+                                                               if 
(tok_is_keyword(tok, &yylval,
+                                                                               
                   K_RETURN, "return"))
+                                                               {
+                                                                       
new->cursor_options |= CURSOR_OPT_RETURN;
+                                                                       tok = 
yylex();
+                                                               }
+                                                       }
+                                                       else if 
(tok_is_keyword(tok, &yylval,
+                                                                               
           K_WITHOUT, "without"))
+                                                       {
+                                                               tok = yylex();
+                                                               if 
(tok_is_keyword(tok, &yylval,
+                                                                               
                   K_RETURN, "return"))
+                                                               {
+                                                                       
new->cursor_options |= 0;
+                                                                       tok = 
yylex();
+                                                               }
+                                                       }
+
                                                        if (tok != K_FOR)
                                                                yyerror("syntax 
error, expected \"FOR\"");
 
@@ -2552,6 +2596,8 @@ unreserved_keyword        :
                                | K_USE_VARIABLE
                                | K_VARIABLE_CONFLICT
                                | K_WARNING
+                               | K_WITH
+                               | K_WITHOUT
                                ;
 
 %%
diff --git a/src/pl/plpgsql/src/pl_unreserved_kwlist.h 
b/src/pl/plpgsql/src/pl_unreserved_kwlist.h
index 466bdc7a20..8a8f8ea47a 100644
--- a/src/pl/plpgsql/src/pl_unreserved_kwlist.h
+++ b/src/pl/plpgsql/src/pl_unreserved_kwlist.h
@@ -109,3 +109,5 @@ PG_KEYWORD("use_column", K_USE_COLUMN)
 PG_KEYWORD("use_variable", K_USE_VARIABLE)
 PG_KEYWORD("variable_conflict", K_VARIABLE_CONFLICT)
 PG_KEYWORD("warning", K_WARNING)
+PG_KEYWORD("with", K_WITH)
+PG_KEYWORD("without", K_WITHOUT)
diff --git a/src/pl/plpgsql/src/sql/plpgsql_with_return.sql 
b/src/pl/plpgsql/src/sql/plpgsql_with_return.sql
new file mode 100644
index 0000000000..08da362bce
--- /dev/null
+++ b/src/pl/plpgsql/src/sql/plpgsql_with_return.sql
@@ -0,0 +1,64 @@
+CREATE TABLE drs_test1 (a int);
+INSERT INTO drs_test1 VALUES (1), (2), (3);
+CREATE TABLE drs_test2 (x text, y text);
+INSERT INTO drs_test2 VALUES ('abc', 'def'), ('foo', 'bar');
+
+
+CREATE PROCEDURE pdrstest1(x int)
+LANGUAGE plpgsql
+DYNAMIC RESULT SETS 2
+AS $$
+DECLARE
+  c1 CURSOR WITH RETURN (y int) FOR SELECT a * y AS ay FROM drs_test1;
+  c2 CURSOR WITH RETURN FOR SELECT * FROM drs_test2;
+BEGIN
+  OPEN c1(x);
+  IF x > 1 THEN
+    OPEN c2;
+  END IF;
+END;
+$$;
+
+CALL pdrstest1(1);
+CALL pdrstest1(2);
+
+
+DO $$
+DECLARE
+  c1 CURSOR WITH RETURN (y int) FOR SELECT a * y AS ay FROM drs_test1;
+  c2 CURSOR WITH RETURN FOR SELECT * FROM drs_test2;
+BEGIN
+  OPEN c1(1);
+  OPEN c2;
+END;
+$$;
+
+
+-- (The result sets of the called procedure are not returned.)
+DO $$
+BEGIN
+  CALL pdrstest1(1);
+END;
+$$;
+
+
+CREATE PROCEDURE pdrstest2(x int)
+LANGUAGE plpgsql
+DYNAMIC RESULT SETS 2
+AS $$
+DECLARE
+  c1 refcursor;
+  c2 refcursor;
+BEGIN
+  OPEN c1 WITH RETURN FOR SELECT a * x AS ax FROM drs_test1;
+  IF x > 1 THEN
+    OPEN c2 SCROLL WITH RETURN FOR SELECT * FROM drs_test2;
+  END IF;
+END;
+$$;
+
+CALL pdrstest2(1);
+CALL pdrstest2(2);
+
+
+DROP TABLE drs_test1, drs_test2;
diff --git a/src/test/regress/expected/dynamic_result_sets.out 
b/src/test/regress/expected/dynamic_result_sets.out
new file mode 100644
index 0000000000..7b2529c99e
--- /dev/null
+++ b/src/test/regress/expected/dynamic_result_sets.out
@@ -0,0 +1,129 @@
+CREATE TABLE drs_test1 (a int);
+INSERT INTO drs_test1 VALUES (1), (2), (3);
+CREATE TABLE drs_test2 (x text, y text);
+INSERT INTO drs_test2 VALUES ('abc', 'def'), ('foo', 'bar');
+-- return a couple of result sets from a procedure
+CREATE PROCEDURE pdrstest1()
+LANGUAGE SQL
+DYNAMIC RESULT SETS 2
+AS $$
+DECLARE c1 CURSOR WITH RETURN FOR SELECT * FROM drs_test1;
+DECLARE c2 CURSOR WITH RETURN FOR SELECT * FROM drs_test2;
+$$;
+CALL pdrstest1();
+ a 
+---
+ 1
+ 2
+ 3
+(3 rows)
+
+  x  |  y  
+-----+-----
+ abc | def
+ foo | bar
+(2 rows)
+
+CALL pdrstest1() \bind \g
+ERROR:  dynamic result sets are not yet supported in extended query protocol
+-- return too many result sets from a procedure
+CREATE PROCEDURE pdrstest2()
+LANGUAGE SQL
+DYNAMIC RESULT SETS 1
+AS $$
+DECLARE c1 CURSOR WITH RETURN FOR SELECT * FROM drs_test1;
+DECLARE c2 CURSOR WITH RETURN FOR SELECT * FROM drs_test2;
+$$;
+CALL pdrstest2();
+WARNING:  attempt to return too many result sets
+ a 
+---
+ 1
+ 2
+ 3
+(3 rows)
+
+  x  |  y  
+-----+-----
+ abc | def
+ foo | bar
+(2 rows)
+
+CALL pdrstest2() \bind \g
+WARNING:  attempt to return too many result sets
+ERROR:  dynamic result sets are not yet supported in extended query protocol
+-- nested calls
+CREATE PROCEDURE pdrstest3()
+LANGUAGE SQL
+DYNAMIC RESULT SETS 1
+AS $$
+CALL pdrstest1();
+DECLARE c3 CURSOR WITH RETURN FOR SELECT * FROM drs_test1 WHERE a < 2;
+$$;
+-- (The result sets of the called procedure are not returned.)
+CALL pdrstest3();
+ a 
+---
+ 1
+(1 row)
+
+CALL pdrstest3() \bind \g
+ERROR:  dynamic result sets are not yet supported in extended query protocol
+-- both out parameter and result sets
+CREATE PROCEDURE pdrstest4(INOUT a text)
+LANGUAGE SQL
+DYNAMIC RESULT SETS 1
+AS $$
+DECLARE c4 CURSOR WITH RETURN FOR SELECT * FROM drs_test1;
+SELECT a || a;
+$$;
+CALL pdrstest4('x');
+ a  
+----
+ xx
+(1 row)
+
+ a 
+---
+ 1
+ 2
+ 3
+(3 rows)
+
+CALL pdrstest4($1) \bind 'y' \g
+ERROR:  dynamic result sets are not yet supported in extended query protocol
+-- test the nested error handling
+CREATE TABLE drs_test_dummy (a int);
+CREATE PROCEDURE pdrstest5a()
+LANGUAGE SQL
+DYNAMIC RESULT SETS 1
+AS $$
+DECLARE c5a CURSOR WITH RETURN FOR SELECT * FROM drs_test_dummy;
+$$;
+CREATE PROCEDURE pdrstest5b()
+LANGUAGE SQL
+DYNAMIC RESULT SETS 1
+AS $$
+CALL pdrstest5a();
+$$;
+DROP TABLE drs_test_dummy;
+CALL pdrstest5b();
+ERROR:  relation "drs_test_dummy" does not exist
+LINE 2: DECLARE c5a CURSOR WITH RETURN FOR SELECT * FROM drs_test_du...
+                                                         ^
+QUERY:  
+DECLARE c5a CURSOR WITH RETURN FOR SELECT * FROM drs_test_dummy;
+
+CONTEXT:  SQL function "pdrstest5a" during startup
+SQL function "pdrstest5b" statement 1
+CALL pdrstest5b() \bind \g
+ERROR:  relation "drs_test_dummy" does not exist
+LINE 2: DECLARE c5a CURSOR WITH RETURN FOR SELECT * FROM drs_test_du...
+                                                         ^
+QUERY:  
+DECLARE c5a CURSOR WITH RETURN FOR SELECT * FROM drs_test_dummy;
+
+CONTEXT:  SQL function "pdrstest5a" during startup
+SQL function "pdrstest5b" statement 1
+-- cleanup
+DROP TABLE drs_test1, drs_test2;
diff --git a/src/test/regress/parallel_schedule 
b/src/test/regress/parallel_schedule
index 15e015b3d6..57f3c9b6cd 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -43,7 +43,7 @@ test: copy copyselect copydml insert insert_conflict
 # Note: many of the tests in later groups depend on create_index
 # ----------
 test: create_function_c create_misc create_operator create_procedure 
create_table create_type
-test: create_index create_index_spgist create_view index_including 
index_including_gist
+test: create_index create_index_spgist create_view index_including 
index_including_gist dynamic_result_sets
 
 # ----------
 # Another group of parallel tests
diff --git a/src/test/regress/sql/dynamic_result_sets.sql 
b/src/test/regress/sql/dynamic_result_sets.sql
new file mode 100644
index 0000000000..ed4a91740e
--- /dev/null
+++ b/src/test/regress/sql/dynamic_result_sets.sql
@@ -0,0 +1,90 @@
+CREATE TABLE drs_test1 (a int);
+INSERT INTO drs_test1 VALUES (1), (2), (3);
+CREATE TABLE drs_test2 (x text, y text);
+INSERT INTO drs_test2 VALUES ('abc', 'def'), ('foo', 'bar');
+
+
+-- return a couple of result sets from a procedure
+
+CREATE PROCEDURE pdrstest1()
+LANGUAGE SQL
+DYNAMIC RESULT SETS 2
+AS $$
+DECLARE c1 CURSOR WITH RETURN FOR SELECT * FROM drs_test1;
+DECLARE c2 CURSOR WITH RETURN FOR SELECT * FROM drs_test2;
+$$;
+
+CALL pdrstest1();
+CALL pdrstest1() \bind \g
+
+
+-- return too many result sets from a procedure
+
+CREATE PROCEDURE pdrstest2()
+LANGUAGE SQL
+DYNAMIC RESULT SETS 1
+AS $$
+DECLARE c1 CURSOR WITH RETURN FOR SELECT * FROM drs_test1;
+DECLARE c2 CURSOR WITH RETURN FOR SELECT * FROM drs_test2;
+$$;
+
+CALL pdrstest2();
+CALL pdrstest2() \bind \g
+
+
+-- nested calls
+
+CREATE PROCEDURE pdrstest3()
+LANGUAGE SQL
+DYNAMIC RESULT SETS 1
+AS $$
+CALL pdrstest1();
+DECLARE c3 CURSOR WITH RETURN FOR SELECT * FROM drs_test1 WHERE a < 2;
+$$;
+
+-- (The result sets of the called procedure are not returned.)
+CALL pdrstest3();
+CALL pdrstest3() \bind \g
+
+
+-- both out parameter and result sets
+
+CREATE PROCEDURE pdrstest4(INOUT a text)
+LANGUAGE SQL
+DYNAMIC RESULT SETS 1
+AS $$
+DECLARE c4 CURSOR WITH RETURN FOR SELECT * FROM drs_test1;
+SELECT a || a;
+$$;
+
+CALL pdrstest4('x');
+CALL pdrstest4($1) \bind 'y' \g
+
+
+-- test the nested error handling
+
+CREATE TABLE drs_test_dummy (a int);
+
+CREATE PROCEDURE pdrstest5a()
+LANGUAGE SQL
+DYNAMIC RESULT SETS 1
+AS $$
+DECLARE c5a CURSOR WITH RETURN FOR SELECT * FROM drs_test_dummy;
+$$;
+
+CREATE PROCEDURE pdrstest5b()
+LANGUAGE SQL
+DYNAMIC RESULT SETS 1
+AS $$
+CALL pdrstest5a();
+$$;
+
+DROP TABLE drs_test_dummy;
+
+CALL pdrstest5b();
+CALL pdrstest5b() \bind \g
+
+
+-- cleanup
+
+DROP TABLE drs_test1, drs_test2;

base-commit: 4fc53819a45fe6e7233a69bb279557b2070dcc40
-- 
2.39.2

From 552a7fa9e79578b37f375579f7cb46cd897d100f Mon Sep 17 00:00:00 2001
From: Peter Eisentraut <pe...@eisentraut.org>
Date: Fri, 24 Feb 2023 12:21:40 +0100
Subject: [PATCH v8 2/2] WIP: Dynamic result sets in extended query protocol

This is currently broken due to/since acb7e4eb6b.

TODO: consider minor protocol version bump (3.1)
---
 doc/src/sgml/protocol.sgml                    | 19 +++++++++++
 src/backend/tcop/postgres.c                   | 32 ++++++++++++++++---
 src/backend/tcop/pquery.c                     |  6 ++++
 src/include/utils/portal.h                    |  2 ++
 src/interfaces/libpq/fe-protocol3.c           |  6 ++--
 .../regress/expected/dynamic_result_sets.out  | 31 +++++++++++++++---
 6 files changed, 84 insertions(+), 12 deletions(-)

diff --git a/doc/src/sgml/protocol.sgml b/doc/src/sgml/protocol.sgml
index 93fc7167d4..ec605b12b5 100644
--- a/doc/src/sgml/protocol.sgml
+++ b/doc/src/sgml/protocol.sgml
@@ -959,6 +959,25 @@ <title>Extended Query</title>
     an empty query string), ErrorResponse, or PortalSuspended.
    </para>
 
+   <para>
+    Executing a portal may give rise to a <firstterm>dynamic result set
+    sequence</firstterm>.  That means the command contained in the portal
+    created additional result sets beyond what it normally returns.  (The
+    typical example is calling a stored procedure that creates dynamic result
+    sets.)  Dynamic result sets are issued after whatever response the main
+    command issued.  Each dynamic result set begins with a RowDescription
+    message followed by zero or more DataRow messages.  (Since, as explained
+    above, an Execute message normally does not respond with a RowDescription,
+    the appearance of the first RowDescription marks the end of the primary
+    result set of the portal and the beginning of the first dynamic result
+    set.)  The CommandComplete message that concludes the Execute message
+    response follows <emphasis>after</emphasis> all dynamic result sets.  Note
+    that dynamic result sets cannot, by their nature, be decribed prior to the
+    execution of the portal.  Multiple executions of the same prepared
+    statement could result in dynamic result sets with different row
+    descriptions being returned.
+   </para>
+
    <para>
     At completion of each series of extended-query messages, the frontend
     should issue a Sync message.  This parameterless message causes the
diff --git a/src/backend/tcop/postgres.c b/src/backend/tcop/postgres.c
index 98ac9aa012..89da5c7512 100644
--- a/src/backend/tcop/postgres.c
+++ b/src/backend/tcop/postgres.c
@@ -2086,6 +2086,7 @@ exec_execute_message(const char *portal_name, long 
max_rows)
        const char *sourceText;
        const char *prepStmtName;
        ParamListInfo portalParams;
+       ListCell   *lc;
        bool            save_log_statement_stats = log_statement_stats;
        bool            is_xact_command;
        bool            execute_is_fetch;
@@ -2226,10 +2227,33 @@ exec_execute_message(const char *portal_name, long 
max_rows)
                                                  receiver,
                                                  &qc);
 
-       if (GetReturnableCursors())
-               ereport(ERROR,
-                               errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
-                               errmsg("dynamic result sets are not yet 
supported in extended query protocol"));
+       /*
+        * Run portals for dynamic result sets.
+        */
+       foreach (lc, GetReturnableCursors())
+       {
+               Portal dyn_portal = lfirst(lc);
+
+               if (dest == DestRemoteExecute)
+                       SetRemoteDestReceiverParams(receiver, dyn_portal);
+
+               PortalSetResultFormat(dyn_portal, 1, &portal->dynamic_format);
+
+               SendRowDescriptionMessage(&row_description_buf,
+                                                                 
dyn_portal->tupDesc,
+                                                                 
FetchPortalTargetList(dyn_portal),
+                                                                 
dyn_portal->formats);
+
+               PortalRun(dyn_portal,
+                                 FETCH_ALL,
+                                 true,
+                                 true,
+                                 receiver,
+                                 receiver,
+                                 NULL);
+
+               PortalDrop(dyn_portal, false);
+       }
 
        receiver->rDestroy(receiver);
 
diff --git a/src/backend/tcop/pquery.c b/src/backend/tcop/pquery.c
index 5f0248acc5..6469940935 100644
--- a/src/backend/tcop/pquery.c
+++ b/src/backend/tcop/pquery.c
@@ -641,6 +641,8 @@ PortalSetResultFormat(Portal portal, int nFormats, int16 
*formats)
                                         errmsg("bind message has %d result 
formats but query has %d columns",
                                                        nFormats, natts)));
                memcpy(portal->formats, formats, natts * sizeof(int16));
+
+               portal->dynamic_format = 0;
        }
        else if (nFormats > 0)
        {
@@ -649,12 +651,16 @@ PortalSetResultFormat(Portal portal, int nFormats, int16 
*formats)
 
                for (i = 0; i < natts; i++)
                        portal->formats[i] = format1;
+
+               portal->dynamic_format = format1;
        }
        else
        {
                /* use default format for all columns */
                for (i = 0; i < natts; i++)
                        portal->formats[i] = 0;
+
+               portal->dynamic_format = 0;
        }
 }
 
diff --git a/src/include/utils/portal.h b/src/include/utils/portal.h
index 6f04362dfe..55406b8654 100644
--- a/src/include/utils/portal.h
+++ b/src/include/utils/portal.h
@@ -170,6 +170,8 @@ typedef struct PortalData
        TupleDesc       tupDesc;                /* descriptor for result tuples 
*/
        /* and these are the format codes to use for the columns: */
        int16      *formats;            /* a format code for each column */
+       /* Format code for dynamic result sets */
+       int16           dynamic_format;
 
        /*
         * Outermost ActiveSnapshot for execution of the portal's queries.  For
diff --git a/src/interfaces/libpq/fe-protocol3.c 
b/src/interfaces/libpq/fe-protocol3.c
index 8ab6a88416..863a09cf74 100644
--- a/src/interfaces/libpq/fe-protocol3.c
+++ b/src/interfaces/libpq/fe-protocol3.c
@@ -320,10 +320,8 @@ pqParseInput3(PGconn *conn)
                                        {
                                                /*
                                                 * A new 'T' message is treated 
as the start of
-                                                * another PGresult.  (It is 
not clear that this is
-                                                * really possible with the 
current backend.) We stop
-                                                * parsing until the 
application accepts the current
-                                                * result.
+                                                * another PGresult.  We stop 
parsing until the
+                                                * application accepts the 
current result.
                                                 */
                                                conn->asyncStatus = 
PGASYNC_READY;
                                                return;
diff --git a/src/test/regress/expected/dynamic_result_sets.out 
b/src/test/regress/expected/dynamic_result_sets.out
index 7b2529c99e..3584f1ec8c 100644
--- a/src/test/regress/expected/dynamic_result_sets.out
+++ b/src/test/regress/expected/dynamic_result_sets.out
@@ -25,7 +25,14 @@ CALL pdrstest1();
 (2 rows)
 
 CALL pdrstest1() \bind \g
-ERROR:  dynamic result sets are not yet supported in extended query protocol
+ a 
+---
+ 1
+ 2
+ 3
+(3 rows)
+
+server sent data ("D" message) without prior row description ("T" message)
 -- return too many result sets from a procedure
 CREATE PROCEDURE pdrstest2()
 LANGUAGE SQL
@@ -51,7 +58,14 @@ WARNING:  attempt to return too many result sets
 
 CALL pdrstest2() \bind \g
 WARNING:  attempt to return too many result sets
-ERROR:  dynamic result sets are not yet supported in extended query protocol
+ a 
+---
+ 1
+ 2
+ 3
+(3 rows)
+
+server sent data ("D" message) without prior row description ("T" message)
 -- nested calls
 CREATE PROCEDURE pdrstest3()
 LANGUAGE SQL
@@ -68,7 +82,11 @@ CALL pdrstest3();
 (1 row)
 
 CALL pdrstest3() \bind \g
-ERROR:  dynamic result sets are not yet supported in extended query protocol
+ a 
+---
+ 1
+(1 row)
+
 -- both out parameter and result sets
 CREATE PROCEDURE pdrstest4(INOUT a text)
 LANGUAGE SQL
@@ -91,7 +109,12 @@ CALL pdrstest4('x');
 (3 rows)
 
 CALL pdrstest4($1) \bind 'y' \g
-ERROR:  dynamic result sets are not yet supported in extended query protocol
+ a  
+----
+ yy
+(1 row)
+
+server sent data ("D" message) without prior row description ("T" message)
 -- test the nested error handling
 CREATE TABLE drs_test_dummy (a int);
 CREATE PROCEDURE pdrstest5a()
-- 
2.39.2

Reply via email to