Thread: Multi-column returns from pgsql

Multi-column returns from pgsql

From
"Mark R. Dingee"
Date:
Hi Everyone,

Does anyone know if/how it's possible to return multi-column sets from a pgsql 
function?  Right now I'm using something like the following as a work around

CREATE OR REPLACE FUNCTION my_func() returns SETOF TEXT AS '
DECLARE   rec record;
BEGIN   FOR rec IN SELECT txt1, txt2 FROM mytable LOOP      RETURN NEXT rec.txt1;      RETURN NEXT rec.txt2;   END
LOOP;  RETURN;
 
END;' language 'plpgsql';

which leaves me parsing multiple records to achieve the desired end result.

Anyone have any thoughts?

Thanks,
Mark




Re: Multi-column returns from pgsql

From
"Jim Buttafuoco"
Date:
Mark,

Instead of  RETURN NEXT rec.txt1; RETURN NEXT rec.txt2; just use RETURN NEXT rec;

then your select statement would be 
select * from my_func() as (txt1 text,txt2 text);

Jim




---------- Original Message -----------
From: "Mark R. Dingee" <mark.dingee@cox.net>
To: pgsql-sql@postgresql.org
Sent: Fri, 22 Jul 2005 11:49:21 -0400
Subject: [SQL] Multi-column returns from pgsql

> Hi Everyone,
> 
> Does anyone know if/how it's possible to return multi-column sets from a pgsql 
> function?  Right now I'm using something like the following as a work around
> 
> CREATE OR REPLACE FUNCTION my_func() returns SETOF TEXT AS '
> DECLARE
>     rec record;
> BEGIN
>     FOR rec IN SELECT txt1, txt2 FROM mytable LOOP
>        RETURN NEXT rec.txt1;
>        RETURN NEXT rec.txt2;
>     END LOOP;
>     RETURN;
> END;' language 'plpgsql';
> 
> which leaves me parsing multiple records to achieve the desired end result.
> 
> Anyone have any thoughts?
> 
> Thanks,
> Mark
> 
> ---------------------------(end of broadcast)---------------------------
> TIP 9: In versions below 8.0, the planner will ignore your desire to
>        choose an index scan if your joining column's datatypes do not
>        match
------- End of Original Message -------



Re: Multi-column returns from pgsql

From
Tony Wasson
Date:
On 7/22/05, Jim Buttafuoco <jim@contactbda.com> wrote:
> Mark,
>
> Instead of  RETURN NEXT rec.txt1; RETURN NEXT rec.txt2; just use RETURN NEXT rec;
>
> then your select statement would be
> select * from my_func() as (txt1 text,txt2 text);
>
> Jim

Besides a simple RETURN NEXT, you'll need to return a SETOF some
composite type. You can do something like

CREATE TYPE twotexts_t AS (txt1 TEXT, txt2 TEXT);

CREATE OR REPLACE FUNCTION my_func() returns SETOF twotexts_t AS '
DECLARE  rec record;
BEGIN  FOR rec IN SELECT txt1, txt2 FROM mytable LOOP     RETURN NEXT  END LOOP;  RETURN;
END;' language 'plpgsql';


Re: Multi-column returns from pgsql

From
"Jim Buttafuoco"
Date:
or just return setof RECORD (version 7.4 +)


---------- Original Message -----------
From: Tony Wasson <ajwasson@gmail.com>
To: jim@contactbda.com
Cc: "Mark R. Dingee" <mark.dingee@cox.net>, pgsql-sql@postgresql.org
Sent: Fri, 22 Jul 2005 11:11:09 -0700
Subject: Re: [SQL] Multi-column returns from pgsql

> On 7/22/05, Jim Buttafuoco <jim@contactbda.com> wrote:
> > Mark,
> > 
> > Instead of  RETURN NEXT rec.txt1; RETURN NEXT rec.txt2; just use RETURN NEXT rec;
> > 
> > then your select statement would be
> > select * from my_func() as (txt1 text,txt2 text);
> > 
> > Jim
> 
> Besides a simple RETURN NEXT, you'll need to return a SETOF some
> composite type. You can do something like
> 
> CREATE TYPE twotexts_t AS (txt1 TEXT, txt2 TEXT);
> 
> CREATE OR REPLACE FUNCTION my_func() returns SETOF twotexts_t AS '
> DECLARE
>    rec record;
> BEGIN
>    FOR rec IN SELECT txt1, txt2 FROM mytable LOOP
>       RETURN NEXT
>    END LOOP;
>    RETURN;
> END;' language 'plpgsql';
> 
> ---------------------------(end of broadcast)---------------------------
> TIP 6: explain analyze is your friend
------- End of Original Message -------