Thread: Re: How to return seto records from seof record function?
On Tue, 2025-02-25 at 17:15 +0300, Олег Самойлов wrote: > Postgresql 17.2 > > How to return seto records from seof record function? I tried pg_background extension: > > CREATE OR REPLACE FUNCTION public.autonomous (p_script text) > RETURNS SETOF record > LANGUAGE plpgsql > VOLATILE STRICT PARALLEL UNSAFE > AS $autonomous$ > DECLARE > l_id integer; > BEGIN > l_id := pg_background_launch(p_script); > RETURN QUERY SELECT * FROM pg_background_result(l_id) AS (r record); > END; > $autonomous$; > > SELECT * FROM autonomous('SELECT now()') AS (a timestamptz); > > SQL Error [42804]: ERROR: structure of query does not match function result type > Detail: Returned type record does not match expected type timestamp with time zone in column 1. > Where: SQL statement "SELECT * FROM pg_background_result(l_id) AS (r record)" > PL/pgSQL function autonomous(text) line 6 at RETURN QUERY You need to be specific: SELECT * FROM pg_background_result(l_id) AS (col1 integer, col2 text, ...); I don't think there is a way to get a generic "record" as result. And even if you could, you would still have to specify a column list when you call autonomous(). Attempts to write functions with polymorphic return type are usually futile. Perhaps you can return a "SETOF jsonb"... Yours, Laurenz Albe
Laurenz Albe <laurenz.albe@cybertec.at> writes: > On Tue, 2025-02-25 at 17:15 +0300, Олег Самойлов wrote: >> How to return seto records from seof record function? I tried pg_background extension: > You need to be specific: > SELECT * FROM pg_background_result(l_id) AS (col1 integer, col2 text, ...); > I don't think there is a way to get a generic "record" as result. > And even if you could, you would still have to specify a column list > when you call autonomous(). plpgsql is indeed not too friendly to this, but perhaps a SQL-language function would serve. That infrastructure seems to be okay with wrapping a generic setof-record result: regression=# \sf array_to_set CREATE OR REPLACE FUNCTION public.array_to_set(anyarray) RETURNS SETOF record LANGUAGE sql IMMUTABLE AS $function$ select i AS "index", $1[i] AS "value" from generate_subscripts($1, 1) i $function$ regression=# create or replace function wrapper(anyarray) RETURNS SETOF record LANGUAGE sql as $$ select 1; select array_to_set($1); $$; CREATE FUNCTION regression=# select wrapper(array[44,55,66]); wrapper --------- (1,44) (2,55) (3,66) (3 rows) regards, tom lane
On Tue, Feb 25, 2025 at 8:47 AM Laurenz Albe <laurenz.albe@cybertec.at> wrote:
I don't think there is a way to get a generic "record" as result.
And even if you could, you would still have to specify a column list
when you call autonomous().
Attempts to write functions with polymorphic return type are usually futile.
Perhaps you can return a "SETOF jsonb"...
There is only one non-jsonb method I'm aware of to convert string query to result without specifying result structure, and that's via refcursors, something like:
begin;
BEGIN;
CREATE FUNCTION f() RETURNS TEXT AS
$$
DECLARE
r REFCURSOR DEFAULT 'test';
BEGIN
OPEN r FOR EXECUTE $z$SELECT 'a' AS a, 1 AS b$z$;
RETURN r;
END;
$$ LANGUAGE PLPGSQL;
SELECT f();
FETCH test;
...
..I doubt it works in OP's case though as this only works to push all the way back to the client app. but it's a neat artifact from yore.
In modern postgres, I think jsonb is the way to go. Function output syntax is one of the clunkiest parts of the language, you are on a freight train to deep dynamic SQL; it sure would be nice if we could somehow pass an output definition somehow in a way the calling function or query could use. This mostly comes up in my experience with analytics, where the column needs are very dynamic and layered.
merlin