Thread: Multiple SRF parameters from query
Hi All, i'm having troubles trying to write a sql query using a Set Returning Function. I have a function foo (ID varchar) that returns a variable number of records. I have also a table (called Anagrafica) that contains a list of IDs to be passed to the function foo. As an example, just say that Anagrafica is like this: Anagrafica ID | n ----+--- aaa | 1 bbb | 5 ccc | 9 ddd | 10 eee | 11 and foo returns this values select * from foo ('aaa') a | b | c --+---+--- 1 | 2 | 3 5 | 9 | 1 select * from foo ('bbb') a | b | c --+---+--- 4 | 0 | 0 2 | 0 | 0 0 | 0 | 0 what i would like to do is write an SQL query that looks something like this (written in simplyfied-pseudo-sql) SELECT FROM anagrafica WHERE n < 5 SELECT * FROM Foo (anagrafica.ID) and that gives as result a table that is the union of foo ('aaa') and foo ('bbb') a | b | c --+---+--- 1 | 2 | 3 5 | 9 | 1 4 | 0 | 0 2 | 0 | 0 0 | 0 | 0 I'm having success if foo returns only a row, but the problem is that foo returns more than one. I think i sould use a join but i couldn't find the right syntax for it. I don't want to create a spefic PL/pgSQL function becase i need to have freedom in selecting IDs from Anagrafica (the one i provided is just an example, the real table is much more complex). I would really appreciate any suggestion. Best regards, Federico.
On Wed, 2005-06-01 at 10:29 +0530, Ramakrishnan Muralidharan wrote: > Hi, > > I am not able to understand "Returning only one row", since 'aaa' having 2 rows and 'bbb' having 3 rows and what criteriasingle row should be returned. Please let me know the expected result and I will try to find out a solution for it. Sorry, it was not clear from my message. I meant that I had success creating a table as a result of multiple invocation of foo (parameter) using the result of an "outer" query as list of parameter to foo, only if foo () is a "normal" function, returning a simple value. It was a misleading sentence anyway, since what i'm asking help for is the case where foo () is a SRF and returns more than 1 row. What i'm trying to do is a query where i get a result of this kind a | b | c --+---+--- 1 | 2 | 3 5 | 9 | 1 4 | 0 | 0 2 | 0 | 0 0 | 0 | 0 given that i select from the table Anagrafica the fields 'aaa' and 'bbb', where the first 2 rows obtained as the result of foo ('aaa') and the latter 3 as the result of foo ('bbb'). Thanks a lot for help ! PS: Sorry for late answering, i had problems with mail. Regards,Federico.
On Sat, Jun 04, 2005 at 06:19:35PM +0200, Federico Pedemonte wrote: > > What i'm trying to do is a query where i get a result of this kind > > a | b | c > --+---+--- > 1 | 2 | 3 > 5 | 9 | 1 > 4 | 0 | 0 > 2 | 0 | 0 > 0 | 0 | 0 > > given that i select from the table Anagrafica the fields 'aaa' and > 'bbb', where the first 2 rows obtained as the result of foo ('aaa') and > the latter 3 as the result of foo ('bbb'). If you don't mind using a deprecated feature that might be removed from future versions of PostgreSQL, then see "SQL Functions Returning Sets" in the documentation: http://www.postgresql.org/docs/8.0/static/xfunc-sql.html#AEN29555 To use the deprecated feature, you could wrap a complex PL/pgSQL SRF inside a simple SQL SRF. The following example works for me in 8.0.3: CREATE TABLE anagrafica ( id text PRIMARY KEY, n integer NOT NULL ); INSERT INTO anagrafica (id, n) VALUES ('aaa', 1); INSERT INTO anagrafica (id, n) VALUES ('bbb', 5); INSERT INTO anagrafica (id, n) VALUES ('ccc', 9); INSERT INTO anagrafica (id, n) VALUES ('ddd', 10); INSERT INTO anagrafica (id, n) VALUES ('eee', 11); CREATE TYPE footype AS ( a integer, b integer, c integer ); CREATE FUNCTION foo(id text) RETURNS SETOF footype AS $$ DECLARE rec footype; BEGIN IF id = 'aaa' THEN rec.a := 1; rec.b := 2; rec.c := 3; RETURN NEXT rec; rec.a := 5; rec.b := 9; rec.c:= 1; RETURN NEXT rec; RETURN; ELSIF id = 'bbb' THEN rec.a := 4; rec.b := 0; rec.c := 0; RETURN NEXT rec; rec.a := 2; rec.b := 0; rec.c := 0; RETURN NEXT rec; rec.a := 0; rec.b := 0; rec.c := 0; RETURN NEXT rec; RETURN; ELSE rec.a := -1; rec.b := -2; rec.c := -3; RETURN NEXT rec; RETURN; END IF; END; $$ LANGUAGE plpgsql STABLE STRICT; CREATE FUNCTION bar(text) RETURNS SETOF footype AS $$ SELECT * FROM foo($1); $$ LANGUAGE sql STABLE STRICT; SELECT (bar(id)).* FROM anagrafica WHERE n <= 5;a | b | c ---+---+---1 | 2 | 35 | 9 | 14 | 0 | 02 | 0 | 00 | 0 | 0 (5 rows) I don't know if there's a way to do this in a simple query without relying on the deprecated behavior. For forward compatibility, you might be better off writing a SRF that makes a query and loops through the results, like this: CREATE FUNCTION baz(query text) RETURNS SETOF footype AS $$ DECLARE rec record; retval footype; BEGIN FOR rec IN EXECUTE query LOOP IF rec.id = 'aaa' THEN retval.a := 1; retval.b := 2; retval.c := 3;RETURN NEXT retval; retval.a := 5; retval.b := 9; retval.c := 1; RETURN NEXT retval; ELSIF rec.id = 'bbb'THEN retval.a := 4; retval.b := 0; retval.c := 0; RETURN NEXT retval; retval.a := 2; retval.b :=0; retval.c := 0; RETURN NEXT retval; retval.a := 0; retval.b := 0; retval.c := 0; RETURN NEXT retval; ELSE retval.a := -1; retval.b := -2; retval.c := -3; RETURN NEXT retval; END IF; END LOOP; RETURN; END; $$ LANGUAGE plpgsql STABLE STRICT; SELECT * FROM baz('SELECT * FROM anagrafica WHERE n <= 5');a | b | c ---+---+---1 | 2 | 35 | 9 | 14 | 0 | 02 | 0 | 00 | 0 | 0 (5 rows) Maybe somebody else can suggest improvements or alternatives. -- Michael Fuhr http://www.fuhr.org/~mfuhr/
Hi, I am not able to understand "Returning only one row", since 'aaa' having 2 rows and 'bbb' having 3 rows and what criteriasingle row should be returned. Please let me know the expected result and I will try to find out a solution for it. for set returning function the following link maybe helpful http://techdocs.postgresql.org/guides/SetReturningFunctions Regards, R.Muralidharan -----Original Message----- From: pgsql-sql-owner@postgresql.org [mailto:pgsql-sql-owner@postgresql.org]On Behalf Of Federico Pedemonte Sent: Tuesday, May 31, 2005 8:23 PM To: pgsql-sql@postgresql.org Subject: [SQL] Multiple SRF parameters from query Hi All, i'm having troubles trying to write a sql query using a Set Returning Function. I have a function foo (ID varchar) that returns a variable number of records. I have also a table (called Anagrafica) that contains a list of IDs to be passed to the function foo. As an example, just say that Anagrafica is like this: Anagrafica ID | n ----+--- aaa | 1 bbb | 5 ccc | 9 ddd | 10 eee | 11 and foo returns this values select * from foo ('aaa') a | b | c --+---+--- 1 | 2 | 3 5 | 9 | 1 select * from foo ('bbb') a | b | c --+---+--- 4 | 0 | 0 2 | 0 | 0 0 | 0 | 0 what i would like to do is write an SQL query that looks something like this (written in simplyfied-pseudo-sql) SELECT FROM anagrafica WHERE n < 5 SELECT * FROM Foo (anagrafica.ID) and that gives as result a table that is the union of foo ('aaa') and foo ('bbb') a | b | c --+---+--- 1 | 2 | 3 5 | 9 | 1 4 | 0 | 0 2 | 0 | 0 0 | 0 | 0 I'm having success if foo returns only a row, but the problem is that foo returns more than one. I think i sould use a join but i couldn't find the right syntax for it. I don't want to create a spefic PL/pgSQL function becase i need to have freedom in selecting IDs from Anagrafica (the one i provided is just an example, the real table is much more complex). I would really appreciate any suggestion. Best regards, Federico. ---------------------------(end of broadcast)--------------------------- TIP 1: subscribe and unsubscribe commands go to majordomo@postgresql.org