Thread: Problem calling stored procedure
Hi all, I've written a stored procedure but am having trouble calling it. The procedure name is called "insert_period" and I am calling using: SELECT insert_period(1::INTEGER,'2005-09-13'::DATE,'2005-09-15'::DATE,'unavailable_periods'); But am getting the error message: ----- ERROR: syntax error at or near "$1" at character 70 QUERY: SELECT * FROM bookings WHERE (start_date, end_date) OVERLAPS (DATE $1 - interval '1 day', DATE $2 + interval '1 day')AND property_id = $3 LIMIT 1 CONTEXT: PL/pgSQL function "insert_period" line 12 at select into variables ------ I've used EMS PostgreSQL Manager to write the function, and have successfully used the debugger to step through the functionusing various calling arguments without issue - I only get this problem when trying to call the function througha client. Research on this revealed problems when variable names are named after existing postgres functions/tables/columns, but Ito my knowledge there is nothing in the database named the same of my arguments. I've tried renaming them all to randomnames, but to no avail. I've also tried declaring the variables as ALIAS FOR in the DECLARE section, but again no luck.The other thing that concerns me is that the error shows $1 being used as a DATE argument, I would have thought 'prop_id'(See below) would have been $1? I have included the function below - Anyone have any ideas? Cheers, Neil. ----- CREATE OR REPLACE FUNCTION "public"."insert_period" (prop_id integer, new_start_date date, new_end_date date, into_tablevarchar) RETURNS integer AS $body$ DECLARE cur_overlap refcursor; new_id INTEGER; num_entries INTEGER; row_one record; row_two record; clashes record; BEGIN LOCK TABLE calendar_entries IN EXCLUSIVE MODE; SELECT INTO clashes * FROM bookings WHERE (start_date, end_date) OVERLAPS (DATE new_start_date - interval '1 day', DATEnew_end_date + interval '1 day') AND property_id = prop_id LIMIT 1; IF NOT FOUND THEN DELETE FROM calendar_entries WHERE property_id = prop_id AND (start_date >= new_start_date) AND (end_date <= new_end_date); OPEN cur_overlap FOR SELECT *, pg_class.relname AS table FROM calendar_entries WHERE (start_date, end_date) OVERLAPS(new_start_date - interval '2 days', new_end_date + interval '2 days') AND property_id = prop_id AND pg_class.oid= tableoid ORDER BY start_date; GET DIAGNOSTICS num_entries = ROW_COUNT; IF (num_entries = 1) THEN /* We're overlapping one row. Either we're enveloped by a single row, or we have one row overlappingeither the start date or the end date. */ FETCH cur_overlap INTO row_one; IF (row_one.start_date <= new_start_date) AND (row_one.end_date >= new_end_date) THEN /* We're enveloped.The enveloping row needs to be split in to two so that we can insert ourselves. */ IF row_one.table = into_table THEN /* This period is already marked appropriately. Do nothing. */ ELSE /* We need to perform a split/insert. 1. Adjust the end date of the enveloping row to the new start - 1 day. 2. Insert a new row as the same type as the enveloping row from new_end_date+ 1 to the existing end date. 3. Insert the new row in to the required table */ EXECUTE 'UPDATE ' || row_one.table || ' SET end_date = DATE ''' || new_start_date || ''' - interval ''1day'' WHERE id = ' || row_one.id; EXECUTE 'INSERT INTO ' || row_one.table || ' (start_date, end_date)VALUES (DATE ''' || new_end_date || ''' + interval ''1 day'', DATE ''' || row_one.end_date || ''')'; EXECUTE 'INSERT INTO ' || into_table || ' (start_date, end_date) VALUES (DATE ''' || new_start_date || ''', DATE '''|| new_end_date || ''')'; END IF; ELSIF row_one.start_date <= new_start_date THEN /* This row is earlier than the proposed period - It's overlapping our start date- But is it of the same type? */ IF row_one.table = into_table THEN /* A single row overlapping the start only and of the same type - Update the enddate and return the existing row ID */ EXECUTE 'UPDATE ' || into_table || ' SET end_date =' || DATE || '''' || new_end_date || ''' WHERE id = ' || row_one.id; RETURN row_one.id; ELSE /* Single row, overlapping the start, and of a different type. Trim back the existingrow and Insert and return newly generated ID. */ EXECUTE 'INSERT INTO ' || into_table || '(start_date, end_date) VALUES (DATE ''' || new_start_date || ''', DATE ''' ||new_end_date || ''')'; new_id = EXECUTE('SELECT currval(''calendar_entry_id_seq'')'); RETURN new_id; END IF; ELSIF row_one.start_date > new_end_date THEN /* This period is after the proposed period */ IF row_one.table = into_table THEN /* Single row, overlapping the end, and of the same type. Update the start_date ofthe existing row, and return it's id. */ EXECUTE 'UPDATE ' || into_table || ' SET start_date = DATE ''' || new_start_date || ''' WHEREid = ' || row_one.id; RETURN row_one.id; ELSE /* Single row, overlapping the end, and of a different type. Update the existingrows start_date, insert a new row, and return the new ID. */ EXECUTE 'UPDATE ' || into_table || ' SET start_date = DATE ''' || new_end_date || ''' + interval ''1day'''; EXECUTE 'INSERT INTO ' || into_table || ' (start_date, end_date) VALUES (DATE '''|| new_start || ''',DATE ''' || new_end || ''')'; new_id = EXECUTE('SELECT currval(''calendar_entry_id_seq'')'); RETURN new_id; END IF; END IF; ELSIF (num_entries = 2) THEN FETCH cur_overlap INTO row_one; FETCH cur_overlap INTO row_two; /* Two rows */ IF (row_one.table = into_table) AND (row_two.table = into_table) THEN /* Two overlapping/adjactent rows, both of the same type as the new entry. Delete the secondrow, and adjust the end_date of the first to stretch across until the end o the old second row. */ EXECUTE 'DELETE FROM ' || into_table || ' WHERE id = ' || row_two.id; EXECUTE 'UPDATE' || into_table || ' SET end_date = ' || row_two.end_date || ' WHERE id = ' || row_one.id; RETURNrow_one.id; ELSIF row_one.table = into_table THEN /* Two overlapping/adjacent rows, only the row overlapping the start is of the same type. Adjust the end date of this row to be the end date of the new row.*/ EXECUTE 'UPDATE ' || into_table || ' SET end_date = DATE''' || new_end_date || ''' WHERE id = ' ||row_one.id; RETURN row_one.id; ELSIF row_two.table = into_table THEN /* Two overlapping/adjacent rows, only the row overlapping the end is of the same type. Adjustthe start date of this row to be the start date of the new row.*/ EXECUTE 'UPDATE ' || into_table || ' SET start_date = DATE ''' || new_start_date || ''' WHERE id =' || row_two.id; RETURN row_two.id; ELSE /* Two overlapping/adjacent rows, neither of which are of the same type as the new row */ EXECUTE 'INSERT INTO ' || into_table || ' (start_date,end_date) VALUES (DATE ''' || new_start_date || ''', DATE ''' || new_end_date || ''')'; new_id = EXECUTE("SELECT currval('calendar_entry_id_seq')"); RETURN new_id; END IF; END IF; ELSE RAISE EXCEPTION 'Operation aborted: Clashing booking detected'; END IF; END; $body$ LANGUAGE 'plpgsql' VOLATILE CALLED ON NULL INPUT SECURITY INVOKER; This message is for the designated recipient only and may contain privileged, proprietary, or otherwise private information. If you have received it in error, please notify the sender immediately and delete the original. Any other useof the email by you is prohibited. ---------------------------(end of broadcast)--------------------------- TIP 9: In versions below 8.0, the planner will ignore your desire to choose an index scan if your joining column's datatypesdo not match This message is for the designated recipient only and may contain privileged, proprietary, or otherwise private information. If you have received it in error, please notify the sender immediately and delete the original. Any other useof the email by you is prohibited.
On Mon, Aug 22, 2005 at 03:17:02PM +0200, neil.saunders@accenture.com wrote: > ERROR: syntax error at or near "$1" at character 70 > QUERY: SELECT * FROM bookings WHERE (start_date, end_date) OVERLAPS (DATE $1 - interval '1 day', DATE $2 + interval '1day') AND property_id = $3 LIMIT 1 > CONTEXT: PL/pgSQL function "insert_period" line 12 at select into variables > SELECT INTO clashes * FROM bookings WHERE (start_date, end_date) OVERLAPS (DATE new_start_date - interval '1 day',DATE new_end_date + interval '1 day') AND property_id = prop_id LIMIT 1; Why did you write "DATE new_start_date" and "DATE new_end_date"? That's not the correct syntax for casting, and those variables are already of type DATE anyway. > The other thing that concerns me is that the error shows $1 being > used as a DATE argument, I would have thought 'prop_id' (See below) > would have been $1? $N in the error message refers to a statement preparation argument, not to a function argument. For insight into what PL/pgSQL is doing, see the PREPARE documentation: http://www.postgresql.org/docs/8.0/static/sql-prepare.html -- Michael Fuhr
On Mon, 22 Aug 2005 neil.saunders@accenture.com wrote: > Hi all, > > I've written a stored procedure but am having trouble calling it. > > The procedure name is called "insert_period" and I am calling using: > > SELECT insert_period(1::INTEGER,'2005-09-13'::DATE,'2005-09-15'::DATE,'unavailable_periods'); > > But am getting the error message: > > ----- > > ERROR: syntax error at or near "$1" at character 70 > QUERY: SELECT * FROM bookings WHERE (start_date, end_date) OVERLAPS > (DATE $1 - interval '1 day', DATE $2 + interval '1 day') AND property_id > = $3 LIMIT 1 > CONTEXT: PL/pgSQL function "insert_period" line 12 at select into variables > ------ > > I've used EMS PostgreSQL Manager to write the function, and have > successfully used the debugger to step through the function using > various calling arguments without issue - I only get this problem when > trying to call the function through a client. > > Research on this revealed problems when variable names are named after > existing postgres functions/tables/columns, but I to my knowledge there > is nothing in the database named the same of my arguments. I've tried > renaming them all to random names, but to no avail. I've also tried > declaring the variables as ALIAS FOR in the DECLARE section, but again > no luck. The other thing that concerns me is that the error shows $1 > being used as a DATE argument, I would have thought 'prop_id' (See > below) would have been $1? Me too, however in any case, DATE <blah> is for date literals so I don't believe it's what you want in this case anyway since you're using a variable. I think you'd just want new_start_date, etc, since they're already dates.
Thank you everybody for your help - You were indeed correct - Removing the DATE worked, and ran the function from the client(Although now it fails in the debugger). I'm a little concerned why this didn't work in EMS PostgreSQL Manager debugger- I'll raise a bug tracker regarding this. However, I'm now having another problem regarding getting results back from the SELECT INTO query. OPEN cur_overlap FOR SELECT *, pg_class.RELNAME AS table FROM calendar_entries WHERE (start_date, end_date) OVERLAP (new_start_date,new_end_date) AND property_id = X AND pg_class.oid = tableoid; When I run the query directly in psql (Less the OPEN cur_overlap FOR, and substituting in my test data '2005-09-13', '2005-09-15'),I get one row. However, when the query runs in the function it returns 0 rows. The only thing I can think of is that when the query runs in the psql I get: NOTICE: added missing FROM-clause entry for table "pg_class" I understand why this is happening, but don't know how I would go about re-writing the query to explicitly reference pg_class- I can't write calendar_entries.table_oid, because that changes the meaning of the query. Is this what causing theproblem? When I was using the DATE casts in PostgreSQL Manager and stepping through in the debugger, the same query returned1 row, as expected. I'm very confused and so would appreciate any advice that anyone can offer! This message is for the designated recipient only and may contain privileged, proprietary, or otherwise private information. If you have received it in error, please notify the sender immediately and delete the original. Any other useof the email by you is prohibited.
<neil.saunders@accenture.com> writes: > OPEN cur_overlap FOR SELECT *, pg_class.RELNAME AS table FROM calendar_entries WHERE (start_date, end_date) OVERLAP (new_start_date,new_end_date) AND property_id = X AND pg_class.oid = tableoid; > The only thing I can think of is that when the query runs in the psql I get: > NOTICE: added missing FROM-clause entry for table "pg_class" > I understand why this is happening, but don't know how I would go > about re-writing the query to explicitly reference pg_class - I can't > write calendar_entries.table_oid, because that changes the meaning of > the query. How so? It'd be the same as far as I can see. However, you could avoid any explicit use of pg_class by using the regclass type instead: OPEN cur_overlap FOR SELECT *, tableoid::regclass AS table FROM calendar_entries WHERE (start_date, end_date) OVERLAP (new_start_date,new_end_date) AND property_id = X; As far as the reason for the difference between function execution and manual execution: check for unintended variable substitutions. Which words in the query match variable names in the plpgsql function? Are those only the ones you intended? regards, tom lane
Hi Tom, Thanks for the advice; But I'm still can't get it working. I only have three variables: prop_id, new_start_date, new_end_date,and into_table. I've used the regclass type, and I've tried changing new_start_date and new_end_date to nsdand ned respectively, but still no luck. If there any other avenue of investigation you can think of? I've tried re-writingit as a dynamic query, but Postgres doesn't seem to like that! Thanks once again, Neil. This message is for the designated recipient only and may contain privileged, proprietary, or otherwise private information. If you have received it in error, please notify the sender immediately and delete the original. Any other useof the email by you is prohibited.
Just a quick addendum; I'm finding the number of rows by using GET DIAGNOSTICS num_entries = ROW_COUNT after I open the query, and then branchingdepending on this value - Is there any issue with using this in conjunction with cursors and OPEN FOR SELECT? I'vejust tried using OPEN FOR EXECUTE and quoting the query string, but still no luck - num_entries is still 0. Thanks again, Neil. This message is for the designated recipient only and may contain privileged, proprietary, or otherwise private information. If you have received it in error, please notify the sender immediately and delete the original. Any other useof the email by you is prohibited.
Ok, the whole thing is done and dusted - Thank you everybody for your input. Apologies if I sometimes missed the obvious. For the sake of anyone having the same problems and happens across this post, I learned that: - The result of a cursor assignment cannot be row counted, unless you iterate through it - Fetching a row at the end of a cursor returns an empty set - Fancy IDEs can be deceiving, especially when trying to debug a function. Included below is the finished procedure. Thanks again, Neil. -----Original Message----- DECLARE cur_overlap refcursor; new_id INTEGER; row_one record; row_two record; clashes record; BEGIN LOCK TABLE calendar_entries IN EXCLUSIVE MODE; SELECT INTO clashes * FROM bookings WHERE (start_date, end_date) OVERLAPS (new_start_date - interval '1 day',new_end_date + interval '1 day') AND property_id = prop_id LIMIT 1; IF NOT FOUND THEN DELETE FROM calendar_entries WHERE property_id = prop_id AND (start_date >= new_start_date) AND (end_date <= new_end_date); OPEN cur_overlap FOR EXECUTE 'SELECT *, pg_class.relname AS table FROM calendar_entries, pg_class WHERE (start_date, end_date) OVERLAPS (DATE ''' || new_start_date || ''' - interval ''2 days'', DATE ''' || new_end_date || ''' + interval ''2 days'') AND property_id = ' || prop_id || ' AND pg_class.oid = calendar_entries.tableoid ORDER BY start_date'; FETCH cur_overlap INTO row_one; FETCH cur_overlap INTO row_two; IF (row_two.id IS NULL) THEN /* We're overlapping one row. Either we're enveloped by a single row, or we have one row overlapping either the start date or the end date. */ IF (row_one.start_date <= new_start_date) AND (row_one.end_date >= new_end_date) THEN /* We're enveloped. The enveloping row needs to be split in to two so that we can insert ourselves. */ IF row_one.table = into_table THEN /* This period is already marked appropriately. Do nothing. */ RETURN row_one.id; ELSE /* We need to perform a split/insert. 1. Adjust the end date of the enveloping row to the new start - 1 day. 2. Insert a new row as the same type as the enveloping row from new_end_date + 1 to the existing end date. 3. Insert the new row in to the required table */ EXECUTE 'UPDATE ' || row_one.table || ' SET end_date = DATE ''' || new_start_date || ''' - interval ''1 day'' WHERE id = ' || row_one.id; EXECUTE 'INSERT INTO ' || row_one.table || ' (property_id, start_date, end_date) VALUES (' || prop_id || ', DATE ''' || new_end_date || ''' + interval ''1 day'', DATE ''' || row_one.end_date || ''')'; EXECUTE 'INSERT INTO ' || into_table || ' (property_id, start_date, end_date) VALUES (' || prop_id || ', DATE ''' || new_start_date || ''', DATE ''' || new_end_date || ''')'; SELECT currval('calendar_id_seq') INTO new_id; RETURN new_id; END IF; ELSIF row_one.start_date<= new_start_date THEN /* This row is earlier than the proposed period - It's overlapping our start date - But is it of the same type? */ IF row_one.table = into_table THEN /* A single row overlapping the start only and of the same type - Update the end date and return the existing row ID */ EXECUTE 'UPDATE ' || into_table || ' SET end_date = DATE ''' || new_end_date || ''' WHERE id = ' || row_one.id; RETURN row_one.id; ELSE /* Single row, overlapping the start, and of a different type. Trim back the existing row and Insert and return newly generatedID. */ EXECUTE 'INSERT INTO ' || into_table || '(property_id, start_date, end_date) VALUES (' || prop_id || ', DATE ''' || new_start_date || ''', DATE ''' || new_end_date || ''')'; SELECT currval('calendar_id_seq') INTO new_id; RETURN new_id; END IF; ELSIF row_one.start_date > new_end_date THEN /* This period is after the proposed period */ IF row_one.table = into_table THEN /* Single row, overlapping the end, and of the same type. Update the start_date of the existing row, and return it's id. */ EXECUTE 'UPDATE ' || into_table || ' SET start_date = DATE ''' || new_start_date || ''' WHERE id = ' || row_one.id; RETURN row_one.id; ELSE /* Single row, overlapping the end, and of a different type. Update the existing rows start_date, insert a new row, and return the new ID. */ EXECUTE 'UPDATE ' || into_table || ' SET start_date = DATE ''' || new_end_date || ''' + interval ''1 day'''; EXECUTE 'INSERT INTO ' || into_table || ' (property_id, start_date, end_date) VALUES (' || prop_id || ', DATE ''' || new_start || ''',DATE ''' || new_end || ''')'; SELECT currval('calendar_id_seq') INTO new_id; RETURN new_id; END IF; END IF; ELSIF (row_one.id IS NOT NULL AND row_two.id IS NOT NULL) THEN /* Two rows */ IF (row_one.table = into_table) AND (row_two.table = into_table) THEN /* Two overlapping/adjactent rows, both of the same type as the new entry. Delete the second row, and adjust the end_date of the first to stretch across until the end o the old second row. */ EXECUTE 'DELETE FROM ' || into_table || ' WHERE id = ' || row_two.id; EXECUTE 'UPDATE ' || into_table || ' SET end_date = DATE ''' || row_two.end_date || ''' WHERE id = ' || row_one.id; RETURN row_one.id; ELSIF row_one.table = into_table THEN /* Two overlapping/adjacent rows, only the row overlapping the start is of the same type. Adjust the end date of this row to be the end date of the new row.*/ EXECUTE 'UPDATE ' || into_table || ' SET end_date = DATE''' || new_end_date || ''' WHERE id = ' || row_one.id; RETURN row_one.id; ELSIF row_two.table = into_table THEN /* Two overlapping/adjacent rows, only the row overlapping the end is of the same type. Adjust the start date of this row to be the start date of the new row.*/ EXECUTE 'UPDATE ' || into_table || ' SET start_date = DATE ''' || new_start_date || ''' WHERE id = ' || row_two.id; RETURN row_two.id; ELSE /* Two overlapping/adjacent rows, neither of which are of the same type as the new row */ EXECUTE 'INSERT INTO ' || into_table || ' (property_id, start_date, end_date) VALUES (' || prop_id || ', DATE ''' || new_start_date || ''', DATE ''' || new_end_date || ''')'; SELECT currval('calendar_id_seq') INTO new_id; RETURN new_id; END IF; ELSE /* Row one is null too! We have nothing to fear. Go ahead and insert it */ EXECUTE 'INSERT INTO ' || into_table || ' (property_id, start_date, end_date) VALUES (' || prop_id || ', DATE ''' || new_start_date || ''', DATE ''' || new_end_date || ''')'; SELECT currval('calendar_id_seq') INTO new_id; RETURN new_id; END IF; ELSE RAISE EXCEPTION 'Operation aborted: Clashing booking detected'; END IF; END; This message is for the designated recipient only and may contain privileged, proprietary, or otherwise private information. If you have received it in error, please notify the sender immediately and delete the original. Any other useof the email by you is prohibited.