Thread: Create function problem
*Hello I have a little question In order to know the names and data types of the table "mil_cien_diez" from the schema "public" I run the next 'SELECT' but when I try to create a SQL function and after it I run it, I receive an empty row. Can you see the problem ??* /mydb=> SELECT c.column_name, c.data_type, e.data_type AS element_type mydb-> FROM information_schema.columns c LEFT JOIN information_schema.element_types e mydb-> ON ((c.table_catalog, c.table_schema, c.table_name, 'TABLE', c.dtd_identifier) mydb-> = (e.object_catalog, e.object_schema, e.object_name, e.object_type, e.array_type_identifier)) mydb-> WHERE c.table_schema = 'public' AND c.table_name = 'mil_cien_diez' mydb-> ORDER BY c.ordinal_position; column_name | data_type | element_type -------------+-----------+-------------- miles | smallint | cientos | smallint | decenas | smallint | (3 rows) / *The "CREATE FUNCTION" code is the next :* /mydb=> CREATE OR REPLACE FUNCTION f_describe_tables (text, text mydb(> ,OUT text, OUT text, OUT text) as mydb-> $$ SELECT c.column_name, c.data_type, e.data_type AS element_type mydb$> FROM information_schema.columns c LEFT JOIN information_schema.element_types e mydb$> ON ((c.table_catalog, c.table_schema, c.table_name, 'TABLE', c.dtd_identifier) mydb$> = (e.object_catalog, e.object_schema, e.object_name, e.object_type, e.array_type_identifier)) mydb$> WHERE c.table_schema = $1 AND c.table_name = $2 mydb$> ORDER BY c.ordinal_position; mydb$> $$ LANGUAGE SQL; CREATE FUNCTION mydb=> SELECT * FROM f_describe_tables('pubilc', 'mil_cien_diez'); column1 | column2 | column3 ---------+---------+--------- | | (1 row) / *Thank you, Gustavo *
On Fri, Aug 04, 2006 at 01:51:19AM +0300, gustavo halperin wrote: > In order to know the names and data types of the table "mil_cien_diez" > from the schema "public" I run the next 'SELECT' but when I try to > create a SQL function and after it I run it, I receive an empty row. Can > you see the problem ??* [...] > mydb=> SELECT * FROM f_describe_tables('pubilc', 'mil_cien_diez'); 'public' looks misspelled. Does the query work if you change it? -- Michael Fuhr
Ron St-Pierre wrote: > Check your spelling of public: > SELECT * FROM f_describe_tables('pubilc', 'mil_cien_diez'); > > Ron > *OK thank you, you right, but after write "public" I receive again an empty row, Why??. By the way I wrote a short function:* /mydb=> SELECT c.column_name, c.data_type mydb-> FROM information_schema.columns c mydb-> WHERE c.table_schema = 'public' AND c.table_name = 'mil_cien_diez'; column_name | data_type -------------+----------- miles | smallint cientos | smallint decenas | smallint (3 rows) mydb=> CREATE OR REPLACE FUNCTION f_describe_tables (v_tbl_scm text, v_tbl_name text, mydb(> OUT text, OUT text) as mydb-> $$ SELECT c.column_name, c.data_type mydb$> FROM information_schema.columns c mydb$> WHERE c.table_schema = 'v_tbl_schm' AND c.table_name = 'v_tbl_name' mydb$> $$ LANGUAGE SQL; CREATE FUNCTION mydb=> SELECT * FROM f_describe_tables('public', 'mil_cien_diez'); column1 | column2 ---------+--------- | (1 row) /
On Fri, Aug 04, 2006 at 06:16:41AM +0300, gustavo halperin wrote: > *OK thank you, you right, but after write "public" I receive again an > empty row, Why??. [...] > mydb=> CREATE OR REPLACE FUNCTION f_describe_tables (v_tbl_scm text, > v_tbl_name text, > mydb(> OUT text, OUT text) as > mydb-> $$ SELECT c.column_name, c.data_type > mydb$> FROM information_schema.columns c > mydb$> WHERE c.table_schema = 'v_tbl_schm' AND c.table_name = 'v_tbl_name' > mydb$> $$ LANGUAGE SQL; You've hardcoded the strings 'v_tbl_schm' and 'v_tbl_name' instead of using the function's arguments. I don't think SQL functions support named arguments so you'll need to use $1 and $2. You'll also need to use "RETURNS SETOF record" if you want to return more than one row. -- Michael Fuhr
[Please copy the mailing list on replies so others can contribute to and learn from the discussion.] On Fri, Aug 04, 2006 at 11:20:55AM +0300, gustavo halperin wrote: > Michael Fuhr wrote: > >You've hardcoded the strings 'v_tbl_schm' and 'v_tbl_name' instead > >of using the function's arguments. I don't think SQL functions > >support named arguments so you'll need to use $1 and $2. You'll > >also need to use "RETURNS SETOF record" if you want to return more > >than one row. > > > *OK thank you, I did it. But I receive actually one row, same as you > say, and I need a set of rows for two columns. I don't know how to use > 'RETURNS SETOF' for two columns, This is possible ??, see the function > below:* > /CREATE OR REPLACE FUNCTION f_describe_tables (text, text > OUT text, OUT text) as -- How to use RETURNS SETOF with *two text columns*?? > $$ SELECT c.column_name, c.data_type > FROM information_schema.columns c > WHERE c.table_schema = $1 AND c.table_name = $2 > $$ LANGUAGE SQL;/ Since the function has OUT parameters you can use "RETURNS SETOF record" like this: CREATE FUNCTION funcname(<params>) RETURNS SETOF record AS $$ <body> $$ LANGUAGE SQL; -- Michael Fuhr
Michael Fuhr wrote: > [Please copy the mailing list on replies so others can contribute > to and learn from the discussion.] > > On Fri, Aug 04, 2006 at 11:20:55AM +0300, gustavo halperin wrote: > >> Michael Fuhr wrote: >> >>> You've hardcoded the strings 'v_tbl_schm' and 'v_tbl_name' instead >>> of using the function's arguments. I don't think SQL functions >>> support named arguments so you'll need to use $1 and $2. You'll >>> also need to use "RETURNS SETOF record" if you want to return more >>> than one row. >>> >>> >> *OK thank you, I did it. But I receive actually one row, same as you >> say, and I need a set of rows for two columns. I don't know how to use >> 'RETURNS SETOF' for two columns, This is possible ??, see the function >> below:* >> /CREATE OR REPLACE FUNCTION f_describe_tables (text, text >> OUT text, OUT text) as -- How to use RETURNS SETOF with *two text columns*?? >> $$ SELECT c.column_name, c.data_type >> FROM information_schema.columns c >> WHERE c.table_schema = $1 AND c.table_name = $2 >> $$ LANGUAGE SQL;/ >> > > Since the function has OUT parameters you can use "RETURNS SETOF record" > like this: > > CREATE FUNCTION funcname(<params>) RETURNS SETOF record AS $$ > <body> > $$ LANGUAGE SQL What do you mean with the word "record", can you give an example of how this "record" looks for two columns ? Thank you, Gustavo
On Fri, Aug 04, 2006 at 06:44:16PM +0300, gustavo halperin wrote: > Michael Fuhr wrote: > >Since the function has OUT parameters you can use "RETURNS SETOF record" > >like this: > > > >CREATE FUNCTION funcname(<params>) RETURNS SETOF record AS $$ > ><body> > >$$ LANGUAGE SQL > > What do you mean with the word "record", can you give an example of how > this "record" looks for two columns ? "record" means the literal word "record". Example: CREATE FUNCTION show_tables(OUT schema_name text, OUT table_name text) RETURNS SETOF record AS $$ SELECT table_schema, table_name FROM information_schema.tables; $$ LANGUAGE sql; SELECT * FROM show_tables(); -- Michael Fuhr
Michael Fuhr wrote: > On Fri, Aug 04, 2006 at 06:44:16PM +0300, gustavo halperin wrote: > >> Michael Fuhr wrote: >> >>> Since the function has OUT parameters you can use "RETURNS SETOF record" >>> like this: >>> >>> CREATE FUNCTION funcname(<params>) RETURNS SETOF record AS $$ >>> <body> >>> $$ LANGUAGE SQL >>> >> What do you mean with the word "record", can you give an example of how >> this "record" looks for two columns ? >> > > "record" means the literal word "record". Example: > > CREATE FUNCTION show_tables(OUT schema_name text, OUT table_name text) > RETURNS SETOF record AS $$ > SELECT table_schema, table_name > FROM information_schema.tables; > $$ LANGUAGE sql; > > SELECT * FROM show_tables() Thank you, IS WORK, Thank you very much for your help. Gustavo