Thread: functions are returns columns
Hi all. I want that a function return a table rows (like the doc says at 33.4.4. SQL Functions as Table Sources), but I want the a function return only a few cols, so the same that I select into the func. Modifying the doc example: CREATE TABLE foo (fooid int, foosubid int, fooname text); INSERT INTO foo VALUES (1, 1, 'Joe'); INSERT INTO foo VALUES (1, 2, 'Ed'); INSERT INTO foo VALUES (2, 1, 'Mary'); CREATE FUNCTION getfoo(int) RETURNS foo AS $$ SELECT fooid, foosubid FROM foo WHERE fooid = $1; $$ LANGUAGE SQL; This give me an error: ERROR: return type mismatch in function declared to return foo DETAIL: Final SELECT returns too few columns. CONTEXT: SQL function "getfoo" So, how do it? Thanks, Michele
On 09/11/2007, Michele Petrazzo - Unipex srl <michele.petrazzo@unipex.it> wrote: > Hi all. > I want that a function return a table rows (like the doc says at 33.4.4. > SQL Functions as Table Sources), but I want the a function return only a > few cols, so the same that I select into the func. > Modifying the doc example: > > CREATE TABLE foo (fooid int, foosubid int, fooname text); > INSERT INTO foo VALUES (1, 1, 'Joe'); > INSERT INTO foo VALUES (1, 2, 'Ed'); > INSERT INTO foo VALUES (2, 1, 'Mary'); > > CREATE FUNCTION getfoo(int) RETURNS foo AS $$ > SELECT fooid, foosubid FROM foo WHERE fooid = $1; > $$ LANGUAGE SQL; > > This give me an error: > > ERROR: return type mismatch in function declared to return foo > DETAIL: Final SELECT returns too few columns. > CONTEXT: SQL function "getfoo" > > CREATE FUNCTION getfoo(int) RETURNS foo AS $$ SELECT fooid, foosubid FROM foo WHERE fooid = $1 LIMIT 1; $$ LANGUAGE SQL; or CREATE FUNCTION getfoo(int) RETURNS SETOF foo AS $$ SELECT fooid, foosubid FROM foo WHERE fooid = $1;$$ LANGUAGE SQL; try: SELECT * FROM getfoo(1); Regards Pavel Stehule > So, how do it? > > Thanks, > Michele > > ---------------------------(end of broadcast)--------------------------- > TIP 5: don't forget to increase your free space map settings >
Pavel Stehule wrote: > > CREATE FUNCTION getfoo(int) RETURNS foo AS $$ SELECT fooid, foosubid > FROM foo WHERE fooid = $1 LIMIT 1; $$ LANGUAGE SQL; > this return only one value, I need all the values that return the query > or > > CREATE FUNCTION getfoo(int) RETURNS SETOF foo AS $$ SELECT fooid, > foosubid FROM foo WHERE fooid = $1; $$ LANGUAGE SQL; > this create the same error: ERROR: return type mismatch in function declared to return foo DETAIL: Final SELECT returns too few columns. CONTEXT: SQL function "getfoo I try with: CREATE FUNCTION getfoo (IN int, OUT int, OUT int) AS $$ SELECT fooid, foosubid FROM foo WHERE fooid = $1; $$ LANGUAGE SQL; but only one row returned... Looking for other tips! Thanks, Michele
"Michele Petrazzo - Unipex srl" <michele.petrazzo@unipex.it> writes: > I try with: > CREATE FUNCTION getfoo (IN int, OUT int, OUT int) AS $$ > SELECT fooid, foosubid FROM foo WHERE fooid = $1; > $$ LANGUAGE SQL; > > but only one row returned... You're almost there: CREATE FUNCTION getfoo (IN int, OUT int, OUT int) returns setof record(int,int) AS $$ SELECT fooid, foosubid FROM foo WHEREfooid = $1; $$ LANGUAGE SQL; The return type if present has to match the OUT (and BOTH) parameters. -- Gregory Stark EnterpriseDB http://www.enterprisedb.com Get trained by Bruce Momjian - ask me about EnterpriseDB'sPostgreSQL training!
Gregory Stark <stark@enterprisedb.com> writes: > You're almost there: > CREATE FUNCTION getfoo (IN int, OUT int, OUT int) returns setof record(int,int) AS $$ > SELECT fooid, foosubid FROM foo WHERE fooid = $1; > $$ LANGUAGE SQL; Not quite --- it's just "returns setof record". The output column types are defined by the OUT parameters. The only reason you need the returns clause is to have a place to stick the "setof" specification ... regards, tom lane
"Tom Lane" <tgl@sss.pgh.pa.us> writes: > Gregory Stark <stark@enterprisedb.com> writes: >> You're almost there: > >> CREATE FUNCTION getfoo (IN int, OUT int, OUT int) returns setof record(int,int) AS $$ >> SELECT fooid, foosubid FROM foo WHERE fooid = $1; >> $$ LANGUAGE SQL; > > Not quite --- it's just "returns setof record". The output column types > are defined by the OUT parameters. The only reason you need the returns > clause is to have a place to stick the "setof" specification ... ok... I did test my example before posting it: postgres=# postgres=# CREATE or replace FUNCTION getfoo (IN int, OUT int, OUT int) returns setof record(int,int)AS $$ SELECT1,2 union all select 2,3; $$ LANGUAGE SQL; postgres$# postgres$# CREATE FUNCTION postgres=# postgres=# select * from getfoo(1);column1 | column2 ---------+--------- 1 | 2 2 | 3 (2 rows) -- Gregory Stark EnterpriseDB http://www.enterprisedb.com Ask me about EnterpriseDB's 24x7 Postgres support!
Gregory Stark <stark@enterprisedb.com> writes: > "Tom Lane" <tgl@sss.pgh.pa.us> writes: >> Not quite --- it's just "returns setof record". > I did test my example before posting it: > postgres=# postgres=# CREATE or replace FUNCTION getfoo (IN int, OUT int, OUT int) returns setof record(int,int)AS $$ > SELECT 1,2 union all select 2,3; > $$ LANGUAGE SQL; Interesting --- if you try it in anything older than 8.3, it will fail. What is happening here is that the "(int,int)" is being taken as a typmod (per Teodor's work to allow typmods for all data types), and apparently in this path we never check to see if it's a *valid* typmod. Now typmods are always discarded from function argument and result types, but it seems like we'd better validate that they're legal for the datatype anyway. Otherwise there will be confusion of just this sort. Comments, objections? regards, tom lane