From bfc77c2d3cd0295ca52be54bd856881f4fdca74b Mon Sep 17 00:00:00 2001 From: Peter Eisentraut Date: Thu, 19 Oct 2017 08:21:12 -0400 Subject: [PATCH v1 2/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 invocation. --- doc/src/sgml/ref/declare.sgml | 34 ++++++++++++++++- src/backend/commands/functioncmds.c | 17 ++++++++- src/backend/commands/portalcmds.c | 7 ++++ src/backend/parser/gram.y | 9 ++++- src/backend/tcop/utility.c | 2 +- src/backend/utils/mmgr/portalmem.c | 51 ++++++++++++++++++++++++++ src/include/commands/defrem.h | 3 +- src/include/nodes/parsenodes.h | 19 +++++----- src/include/parser/kwlist.h | 1 + src/include/utils/portal.h | 7 ++++ src/test/regress/expected/create_procedure.out | 27 +++++++++++++- src/test/regress/sql/create_procedure.sql | 19 +++++++++- 12 files changed, 180 insertions(+), 16 deletions(-) diff --git a/doc/src/sgml/ref/declare.sgml b/doc/src/sgml/ref/declare.sgml index a70e2466e5..a817b31889 100644 --- a/doc/src/sgml/ref/declare.sgml +++ b/doc/src/sgml/ref/declare.sgml @@ -27,7 +27,8 @@ DECLARE name [ BINARY ] [ INSENSITIVE ] [ [ NO ] SCROLL ] - CURSOR [ { WITH | WITHOUT } HOLD ] FOR query + CURSOR [ { WITH | WITHOUT } HOLD ] [ { WITH | WITHOUT } RETURN ] + FOR query @@ -120,6 +121,22 @@ Parameters + + WITH RETURN + WITHOUT RETURN + + + This option is only valid for cursors defined inside a procedure. + WITH RETURN specifies that the cursor's result rows + will be provided as a result set of the procedure invocation. To + accomplish that, the cursor must be left open at the end of the + procedure. If multiple WITH RETURN cursors are + declared, then their results will be returned in the order they were + created. WITHOUT RETURN is the default. + + + + query @@ -312,6 +329,21 @@ Examples See for more examples of cursor usage. + + + This example shows how to return multiple result sets from a procedure: + +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(); + + The results of the two cursors will be returned in order from this call. + diff --git a/src/backend/commands/functioncmds.c b/src/backend/commands/functioncmds.c index 1f3156d870..28c26c9a7e 100644 --- a/src/backend/commands/functioncmds.c +++ b/src/backend/commands/functioncmds.c @@ -60,11 +60,13 @@ #include "parser/parse_expr.h" #include "parser/parse_func.h" #include "parser/parse_type.h" +#include "tcop/pquery.h" #include "utils/acl.h" #include "utils/builtins.h" #include "utils/fmgroids.h" #include "utils/guc.h" #include "utils/lsyscache.h" +#include "utils/portal.h" #include "utils/rel.h" #include "utils/syscache.h" #include "utils/tqual.h" @@ -2209,7 +2211,7 @@ ExecuteDoStmt(DoStmt *stmt) * Execute CALL statement */ void -ExecuteCallStmt(ParseState *pstate, CallStmt *stmt) +ExecuteCallStmt(ParseState *pstate, CallStmt *stmt, DestReceiver *dest) { List *targs; ListCell *lc; @@ -2280,4 +2282,17 @@ ExecuteCallStmt(ParseState *pstate, CallStmt *stmt) } FunctionCallInvoke(&fcinfo); + + foreach (lc, GetReturnableCursors()) + { + Portal portal = lfirst(lc); + + PortalRun(portal, + FETCH_ALL, + true, /* XXX top level */ + true, + dest, + dest, + NULL); + } } diff --git a/src/backend/commands/portalcmds.c b/src/backend/commands/portalcmds.c index 76d6cf154c..d763a6fdc7 100644 --- a/src/backend/commands/portalcmds.c +++ b/src/backend/commands/portalcmds.c @@ -140,6 +140,13 @@ PerformCursorOpen(DeclareCursorStmt *cstmt, ParamListInfo params, portal->cursorOptions |= CURSOR_OPT_NO_SCROLL; } + /* + * For returnable cursors, remember the command ID, so we can sort by + * creation order later. + */ + if (portal->cursorOptions & CURSOR_OPT_RETURN) + portal->createCid = GetCurrentCommandId(true); + /* * Start execution, inserting parameters if any. */ diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y index bf460ef83b..7fac779015 100644 --- a/src/backend/parser/gram.y +++ b/src/backend/parser/gram.y @@ -665,7 +665,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query); RANGE READ REAL REASSIGN RECHECK RECURSIVE REF REFERENCES REFERENCING REFRESH REINDEX RELATIVE_P RELEASE RENAME REPEATABLE REPLACE REPLICA - RESET RESTART RESTRICT RETURNING RETURNS REVOKE RIGHT ROLE ROLLBACK ROLLUP + RESET RESTART RESTRICT RETURN RETURNING RETURNS REVOKE RIGHT ROLE ROLLBACK ROLLUP ROUTINE ROUTINES ROW ROWS RULE SAVEPOINT SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT SEQUENCE SEQUENCES @@ -11004,6 +11004,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; } ; /***************************************************************************** @@ -15039,6 +15045,7 @@ unreserved_keyword: | RESET | RESTART | RESTRICT + | RETURN | RETURNS | REVOKE | ROLE diff --git a/src/backend/tcop/utility.c b/src/backend/tcop/utility.c index 4da1f8f643..66e6edce76 100644 --- a/src/backend/tcop/utility.c +++ b/src/backend/tcop/utility.c @@ -658,7 +658,7 @@ standard_ProcessUtility(PlannedStmt *pstmt, break; case T_CallStmt: - ExecuteCallStmt(pstate, castNode(CallStmt, parsetree)); + ExecuteCallStmt(pstate, castNode(CallStmt, parsetree), dest); break; case T_ClusterStmt: diff --git a/src/backend/utils/mmgr/portalmem.c b/src/backend/utils/mmgr/portalmem.c index 89db08464f..fa60761dad 100644 --- a/src/backend/utils/mmgr/portalmem.c +++ b/src/backend/utils/mmgr/portalmem.c @@ -1155,3 +1155,54 @@ ThereAreNoReadyPortals(void) return true; } + +static List * +list_sorted(List *list, int (*cmp) (const void *, const void *)) +{ + int nel = list_length(list); + int i; + ListCell *lc; + void **ptrs; + List *ret = NIL; + + ptrs = palloc(nel * sizeof(void *)); + i = 0; + foreach(lc, list) + ptrs[i++] = lfirst(lc); + + qsort(ptrs, nel, sizeof(void *), cmp); + + for (i = 0; i < nel; i++) + ret = lappend(ret, ptrs[i]); + + return ret; +} + +static int +cmp_portals_by_creation(const void *a, const void *b) +{ + const Portal *pa = a; + const Portal *pb = 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); + } + + return list_sorted(ret, cmp_portals_by_creation); +} diff --git a/src/include/commands/defrem.h b/src/include/commands/defrem.h index 13d5925b18..bc02f5716e 100644 --- a/src/include/commands/defrem.h +++ b/src/include/commands/defrem.h @@ -16,6 +16,7 @@ #include "catalog/objectaddress.h" #include "nodes/parsenodes.h" +#include "tcop/dest.h" #include "utils/array.h" /* commands/dropcmds.c */ @@ -59,7 +60,7 @@ extern void DropTransformById(Oid transformOid); extern void IsThereFunctionInNamespace(const char *proname, int pronargs, oidvector *proargtypes, Oid nspOid); extern void ExecuteDoStmt(DoStmt *stmt); -extern void ExecuteCallStmt(ParseState *pstate, CallStmt *stmt); +extern void ExecuteCallStmt(ParseState *pstate, CallStmt *stmt, DestReceiver *dest); extern Oid get_cast_oid(Oid sourcetypeid, Oid targettypeid, bool missing_ok); extern Oid get_transform_oid(Oid type_id, Oid lang_id, bool missing_ok); extern void interpret_function_parameter_list(ParseState *pstate, diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h index b721240577..c7960ba4f3 100644 --- a/src/include/nodes/parsenodes.h +++ b/src/include/nodes/parsenodes.h @@ -2632,16 +2632,17 @@ typedef struct SecLabelStmt * of the query are always postponed until execution. * ---------------------- */ -#define CURSOR_OPT_BINARY 0x0001 /* BINARY */ -#define CURSOR_OPT_SCROLL 0x0002 /* SCROLL explicitly given */ -#define CURSOR_OPT_NO_SCROLL 0x0004 /* NO SCROLL explicitly given */ -#define CURSOR_OPT_INSENSITIVE 0x0008 /* INSENSITIVE */ -#define CURSOR_OPT_HOLD 0x0010 /* WITH HOLD */ +#define CURSOR_OPT_BINARY (1 << 0) /* BINARY */ +#define CURSOR_OPT_SCROLL (1 << 1) /* SCROLL explicitly given */ +#define CURSOR_OPT_NO_SCROLL (1 << 2) /* NO SCROLL explicitly given */ +#define CURSOR_OPT_INSENSITIVE (1 << 3) /* INSENSITIVE */ +#define CURSOR_OPT_HOLD (1 << 4) /* WITH HOLD */ +#define CURSOR_OPT_RETURN (1 << 5) /* WITH RETURN */ /* these planner-control flags do not correspond to any SQL grammar: */ -#define CURSOR_OPT_FAST_PLAN 0x0020 /* prefer fast-start plan */ -#define CURSOR_OPT_GENERIC_PLAN 0x0040 /* force use of generic plan */ -#define CURSOR_OPT_CUSTOM_PLAN 0x0080 /* force use of custom plan */ -#define CURSOR_OPT_PARALLEL_OK 0x0100 /* parallel mode OK */ +#define CURSOR_OPT_FAST_PLAN (1 << 8) /* prefer fast-start plan */ +#define CURSOR_OPT_GENERIC_PLAN (1 << 9) /* force use of generic plan */ +#define CURSOR_OPT_CUSTOM_PLAN (1 << 10) /* force use of custom plan */ +#define CURSOR_OPT_PARALLEL_OK (1 << 11) /* parallel mode OK */ typedef struct DeclareCursorStmt { diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h index a932400058..566546fe38 100644 --- a/src/include/parser/kwlist.h +++ b/src/include/parser/kwlist.h @@ -335,6 +335,7 @@ PG_KEYWORD("replica", REPLICA, UNRESERVED_KEYWORD) PG_KEYWORD("reset", RESET, UNRESERVED_KEYWORD) PG_KEYWORD("restart", RESTART, UNRESERVED_KEYWORD) PG_KEYWORD("restrict", RESTRICT, UNRESERVED_KEYWORD) +PG_KEYWORD("return", RETURN, UNRESERVED_KEYWORD) PG_KEYWORD("returning", RETURNING, RESERVED_KEYWORD) PG_KEYWORD("returns", RETURNS, UNRESERVED_KEYWORD) PG_KEYWORD("revoke", REVOKE, UNRESERVED_KEYWORD) diff --git a/src/include/utils/portal.h b/src/include/utils/portal.h index cb6f00081d..08890e5c6a 100644 --- a/src/include/utils/portal.h +++ b/src/include/utils/portal.h @@ -130,6 +130,12 @@ typedef struct PortalData SubTransactionId createSubid; /* the creating subxact */ SubTransactionId activeSubid; /* the last subxact with activity */ + /* + * 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) */ const char *commandTag; /* command tag for original query */ @@ -237,5 +243,6 @@ extern PlannedStmt *PortalGetPrimaryStmt(Portal portal); extern void PortalCreateHoldStore(Portal portal); extern void PortalHashTableDeleteAll(void); extern bool ThereAreNoReadyPortals(void); +extern List *GetReturnableCursors(void); #endif /* PORTAL_H */ diff --git a/src/test/regress/expected/create_procedure.out b/src/test/regress/expected/create_procedure.out index eeb129d71f..219118cb16 100644 --- a/src/test/regress/expected/create_procedure.out +++ b/src/test/regress/expected/create_procedure.out @@ -79,8 +79,33 @@ ALTER ROUTINE testfunc1a RENAME TO testfunc1; ALTER ROUTINE ptest1(text) RENAME TO ptest1a; ALTER ROUTINE ptest1a RENAME TO ptest1; DROP ROUTINE testfunc1(int); +-- dynamic result sets +CREATE TABLE cp_test2 (a int); +INSERT INTO cp_test2 VALUES (1), (2), (3); +CREATE TABLE cp_test3 (x text, y text); +INSERT INTO cp_test3 VALUES ('abc', 'def'), ('foo', 'bar'); +CREATE PROCEDURE pdrstest1() +LANGUAGE SQL +AS $$ +DECLARE c1 CURSOR WITH RETURN FOR SELECT * FROM cp_test2; +DECLARE c2 CURSOR WITH RETURN FOR SELECT * FROM cp_test3; +$$; +CALL pdrstest1(); + a +--- + 1 + 2 + 3 +(3 rows) + + x | y +-----+----- + abc | def + foo | bar +(2 rows) + -- cleanup DROP PROCEDURE ptest1; DROP PROCEDURE ptest2; -DROP TABLE cp_test; +DROP TABLE cp_test, cp_test2, cp_test3; DROP USER regress_user1; diff --git a/src/test/regress/sql/create_procedure.sql b/src/test/regress/sql/create_procedure.sql index f09ba2ad30..911882151c 100644 --- a/src/test/regress/sql/create_procedure.sql +++ b/src/test/regress/sql/create_procedure.sql @@ -69,11 +69,28 @@ CREATE USER regress_user1; DROP ROUTINE testfunc1(int); +-- dynamic result sets + +CREATE TABLE cp_test2 (a int); +INSERT INTO cp_test2 VALUES (1), (2), (3); +CREATE TABLE cp_test3 (x text, y text); +INSERT INTO cp_test3 VALUES ('abc', 'def'), ('foo', 'bar'); + +CREATE PROCEDURE pdrstest1() +LANGUAGE SQL +AS $$ +DECLARE c1 CURSOR WITH RETURN FOR SELECT * FROM cp_test2; +DECLARE c2 CURSOR WITH RETURN FOR SELECT * FROM cp_test3; +$$; + +CALL pdrstest1(); + + -- cleanup DROP PROCEDURE ptest1; DROP PROCEDURE ptest2; -DROP TABLE cp_test; +DROP TABLE cp_test, cp_test2, cp_test3; DROP USER regress_user1; -- 2.14.3