Thread: Problem with functions
I been trying to create several different functions that mimic several stored procedures in MSSQL. The SQL works fine in an interactive SQL, but fails miserably when I try to run/execute a function created using that same SQL. I have been searching web sites and reading what I find but I have not anything on functions that speaks about the issue I'm having. I'm hoping maybe you can provide some input on how to get these functions to work. I am including one of my functions as sample. Here's the function: CREATE OR REPLACE FUNCTION "public"."getappts" (text,date, date) RETURNS SETOF "public"."calendar" AS' SELECT * FROM calendar WHEREevent_date BETWEEN $2 AND $3 AND agent_number IN ( SELECT agent_number FROM agents WHERE rel30a = $1 OR agent_number = $1 ) ORDER BY event_start_time; 'LANGUAGE 'plpgsql' VOLATILE CALLED ON NULL INPUT SECURITY INVOKER; Yes, I need to return multiple rows in the result set. The two tables have the 'agent_number' column in common, ie it is really a foreign key. But it is not set up that way, it's not my database and I can not change it. __________________________________ Do you Yahoo!? New and Improved Yahoo! Mail - Send 10MB messages! http://promotions.yahoo.com/new_mail
On Mon, 20 Sep 2004, Michael Snodgrass wrote: > I been trying to create several different functions > that mimic several stored procedures in MSSQL. > The SQL works fine in an interactive SQL, but fails > miserably when I try to run/execute a function created > using that same SQL. > I have been searching web sites and reading what I > find but I have not anything on functions that speaks > about the issue I'm having. > > I'm hoping maybe you can provide some input on how to > get these functions to work. I am including one of my > functions as sample. > > Here's the function: > CREATE OR REPLACE FUNCTION "public"."getappts" (text, > date, date) > RETURNS SETOF "public"."calendar" AS' > SELECT * > FROM calendar > WHERE > event_date BETWEEN $2 AND $3 > AND agent_number IN > ( SELECT agent_number FROM agents > WHERE rel30a = $1 OR > agent_number = $1 ) > ORDER BY event_start_time; > 'LANGUAGE 'plpgsql' VOLATILE CALLED ON NULL INPUT > SECURITY INVOKER; That's not the syntax for plpgsql set returning functions. I think however, you'd likely be able to make it work by using LANGUAGE 'sql'. If you want more information, there's the set returning function guide on techdocs: http://techdocs.postgresql.org/guides/SetReturningFunctions and a General Bits article at http://www.varlena.com/varlena/GeneralBits/26.html