Обсуждение: returning setof in plpgsql
I have a function that I want to return setof a table in plpgsql.
Here is what I have:
CREATE FUNCTION lookup_account(varchar(32)) RETURNS SETOF accounts AS '
DECLARE aname ALIAS FOR $1; rec RECORD;
BEGIN select into rec * from accounts where accountname = aname; return rec;
END;'
LANGUAGE 'plpgsql';
This seems to hang when I attempt to select it using:
select accountid(
lookup_account('some account')),
accountname(lookup_account('some account')),
type(lookup_account('some account')),
balance(lookup_account('some account'));
Does anyone see a problem w/ my approach??
On Tuesday 21 Jan 2003 10:40 am, David Durst wrote:
> I have a function that I want to return setof a table in plpgsql.
>
> Here is what I have:
>
> CREATE FUNCTION lookup_account(varchar(32)) RETURNS SETOF accounts AS '
> DECLARE
> aname ALIAS FOR $1;
> rec RECORD;
> BEGIN
> select into rec * from accounts where accountname = aname;
> return rec;
> END;'
> LANGUAGE 'plpgsql';
>
> This seems to hang when I attempt to select it using:
>
> select accountid(
> lookup_account('some account')),
> accountname(lookup_account('some account')),
> type(lookup_account('some account')),
> balance(lookup_account('some account'));
>
> Does anyone see a problem w/ my approach??
Hi David,
I've never done this but I seem to remember seeing something about this
recently.
Firstly, I think you need 7.3.1 to do this.
You then have to create a 'type' as being a set of your table. You then
define the function as returning that type.
Sorry I can't be more specific, but as I said, I've never done it.
Gary
>
>
>
>
> ---------------------------(end of broadcast)---------------------------
> TIP 2: you can get off all lists at once with the unregister command
> (send "unregister YourEmailAddressHere" to majordomo@postgresql.org)
--
Gary Stainburn
This email does not contain private or confidential material as it
may be snooped on by interested government parties for unknown
and undisclosed purposes - Regulation of Investigatory Powers Act, 2000
"David Durst" <ddurst@larubber.com> writes:
> CREATE FUNCTION lookup_account(varchar(32)) RETURNS SETOF accounts AS '
> DECLARE
> aname ALIAS FOR $1;
> rec RECORD;
> BEGIN
> select into rec * from accounts where accountname = aname;
> return rec;
> END;'
> LANGUAGE 'plpgsql';
As written, this function can only return a single row (so you hardly
need SETOF). If you intend that it be able to return multiple rows
when accountname is not unique, then you'll need a loop and RETURN NEXT
commands. It'd probably be less tedious to use a SQL-language function:
CREATE FUNCTION lookup_account(varchar(32)) RETURNS SETOF accounts AS '
select * from accounts where accountname = $1'
language sql;
> This seems to hang when I attempt to select it using:
> select accountid(
> lookup_account('some account')),
> accountname(lookup_account('some account')),
> type(lookup_account('some account')),
> balance(lookup_account('some account'));
It works for me (in 7.3), but in any case that's a bad approach: you're
invoking the function four times, independently. Better is
select accountid,accountname,type,balance
from lookup_account('some account');
(again, this syntax requires 7.3)
regards, tom lane
I thought we had an example of this type of function in the docs, but we don't. Here is one: http://www.brasileiro.net:8080/postgres/cookbook/view-recipes.adp?section_id=535&format=long --------------------------------------------------------------------------- Tom Lane wrote: > "David Durst" <ddurst@larubber.com> writes: > > CREATE FUNCTION lookup_account(varchar(32)) RETURNS SETOF accounts AS ' > > DECLARE > > aname ALIAS FOR $1; > > rec RECORD; > > BEGIN > > select into rec * from accounts where accountname = aname; > > return rec; > > END;' > > LANGUAGE 'plpgsql'; > > As written, this function can only return a single row (so you hardly > need SETOF). If you intend that it be able to return multiple rows > when accountname is not unique, then you'll need a loop and RETURN NEXT > commands. It'd probably be less tedious to use a SQL-language function: > > CREATE FUNCTION lookup_account(varchar(32)) RETURNS SETOF accounts AS ' > select * from accounts where accountname = $1' > language sql; > > > This seems to hang when I attempt to select it using: > > > select accountid( > > lookup_account('some account')), > > accountname(lookup_account('some account')), > > type(lookup_account('some account')), > > balance(lookup_account('some account')); > > It works for me (in 7.3), but in any case that's a bad approach: you're > invoking the function four times, independently. Better is > > select accountid,accountname,type,balance > from lookup_account('some account'); > > (again, this syntax requires 7.3) > > regards, tom lane > > ---------------------------(end of broadcast)--------------------------- > TIP 3: if posting/reading through Usenet, please send an appropriate > subscribe-nomail command to majordomo@postgresql.org so that your > message can get through to the mailing list cleanly > -- Bruce Momjian | http://candle.pha.pa.us pgman@candle.pha.pa.us | (610) 359-1001+ If your life is a hard drive, | 13 Roberts Road + Christ can be your backup. | Newtown Square, Pennsylvania19073