Peter Eisentraut wrote: > 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(); > > and that returns those two result sets to the client.
If applied to plpgsql, to return a dynamic result, the following does work: CREATE PROCEDURE test() LANGUAGE plpgsql AS $$ DECLARE query text:= 'SELECT 1 AS col1, 2 AS col2'; BEGIN EXECUTE 'DECLARE c CURSOR WITH RETURN FOR ' || query; END; $$; This method could be used, for instance, to build a pivot with dynamic columns in a single client-server round-trip, which is not possible today with the query-calling-functions interface. More generally, I guess this should help in the whole class of situations where the client needs polymorphic results, which is awesome. But instead of having procedures not return anything, couldn't they return whatever resultset(s) they want to ("no resultset" being just a particular case of "anything"), so that we could leave out cursors and simply write: CREATE PROCEDURE test() LANGUAGE plpgsql AS $$ RETURN QUERY EXECUTE 'SELECT 1 AS col1, 2 AS col2'; END; $$; Or is that not possible or not desirable? Similarly, for the SQL language, I wonder if the above example could be simplified to: CREATE PROCEDURE pdrstest1() LANGUAGE SQL AS $$ SELECT * FROM cp_test2; SELECT * FROM cp_test3; $$; by which the two result sets would go back to the client again without declaring explicit cursors. Currently, it does not error out and no result set is sent. Best regards, -- Daniel Vérité PostgreSQL-powered mailer: http://www.manitou-mail.org Twitter: @DanielVerite -- Sent via pgsql-hackers mailing list (pgsql-hackers@postgresql.org) To make changes to your subscription: http://www.postgresql.org/mailpref/pgsql-hackers