[SQL] 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 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? 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_table varchar) 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', DATE 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 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 overlapping either 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 ''1 day'' 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 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
Re: [SQL] diary constraints
Hi Gary, I've actually just done the same thing - but for renting property. I've implemented the constraint as a trigger (Before insert/update, for each row), that first checks if the start_date is < end_date, and then performs a select on the bookings table using the OVERLAPS function. If there are more than 0 records returned, an exception is raised. I've included the code below. You shouldn't need too many changes to adapt it to your needs! /* This trigger function is responsible for ensuring temporal integrity within the calendar_entries table (And it's children). It ensures that only entries with no overlapping entries. */ BEGIN /* First, check that the start_date > end_date */ IF NEW.start_date > NEW.end_date THEN RAISE EXCEPTION 'ERROR: start_date must not be greater than end_date'; END IF; IF EXISTS ( SELECT 1 FROM calendar_entries WHERE ((start_date,end_date) OVERLAPS (NEW.start_date, NEW.end_date)) AND property_id = NEW.property_id LIMIT 1 ) THEN RAISE EXCEPTION 'cannot add booking - overlapping calendar entries detected'; END IF; RETURN NEW; 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 use of the email by you is prohibited. ---(end of broadcast)--- TIP 2: Don't 'kill -9' the postmaster
Re: [SQL] Problem calling stored procedure
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 the problem? When I was using the DATE casts in PostgreSQL Manager and stepping through in the debugger, the same query returned 1 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 use of the email by you is prohibited. ---(end of broadcast)--- TIP 1: if posting/reading through Usenet, please send an appropriate subscribe-nomail command to [EMAIL PROTECTED] so that your message can get through to the mailing list cleanly
Re: [SQL] Problem calling stored procedure
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 nsd and ned respectively, but still no luck. If there any other avenue of investigation you can think of? I've tried re-writing it 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 use of the email by you is prohibited. ---(end of broadcast)--- TIP 1: if posting/reading through Usenet, please send an appropriate subscribe-nomail command to [EMAIL PROTECTED] so that your message can get through to the mailing list cleanly
Re: [SQL] Problem calling stored procedure
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 branching depending on this value - Is there any issue with using this in conjunction with cursors and OPEN FOR SELECT? I've just 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 use of the email by you is prohibited. ---(end of broadcast)--- TIP 2: Don't 'kill -9' the postmaster
Re: [SQL] Problem calling stored procedure
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 generated ID. */ 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, ove
Re: [SQL] Number of rows in a cursor ?
You cannot count the number of rows in a cursor, unfortunately. I recently ran in to this problem. As far as I am aware, the only way to count them is to either iterate through them, or if you are only expecting one or two, perform multiple FETCHES and test if the record set returned is empty. http://archives.postgresql.org/pgsql-sql/2005-08/msg00208.php OPEN cur_overlap FOR EXECUTE 'SELECT *, '; FETCH cur_overlap INTO row_one; FETCH cur_overlap INTO row_two; IF (row_two.id IS NULL) THEN King regards, 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 use of the email by you is prohibited. ---(end of broadcast)--- TIP 6: explain analyze is your friend