Thread: PL/SQL trouble
Hi, I really don't understand following PostgreSQL 7.2.3 behaviour: $ psql mydb mydb=> CREATE FUNCTION MONDAY(timestamp) RETURNS DATE AS 'DECLARE var1 date;BEGIN select into var1 to_date($1::date-(casewhen extract(DOW from timestamp $1) = 0 then 6 else (extract(DOW from timestamp $1)-1) end)); RETURN var1;END' language 'plpgsql'; CREATE mydb=> select MONDAY('now'::timestamp); NOTICE: Error occurred while executing PL/pgSQL function MONDAY NOTICE: line 4 at select into variables ERROR: parser: parse error at or near "$2" mydb=> \q But I've not inserted any $2 there. I've rewritten the same function in other ways but I've got the same error. I thank you in advance for any hints. Bye, \fer
On Tuesday 26 Nov 2002 8:56 am, Ferruccio Zamuner wrote: > CREATE FUNCTION MONDAY(timestamp) RETURNS DATE AS ' > DECLARE > var1 date; > BEGIN > select into var1 to_date($1::date-(case when extract(DOW from > timestamp $1) = 0 then 6 else (extract(DOW from timestamp $1)-1) end)); > RETURN var1; > END' > language 'plpgsql'; The problem is the to_date(...) - the value is already a date so there isn't a to_date that takes a date. You can also remove the timestamp casts: select into var1 ($1::date - (case when extract(DOW from $1) = 0 then 6 else (extract(DOW from $1) - 1 ) end ) ); If you put your function in a text file and create it with psql -f you can pinpoint errors more easily. In this case, the $2 was complaining about the second (expected) paramater to to_date I think. -- Richard Huxton
> I really don't understand following PostgreSQL 7.2.3 behaviour: > > $ psql mydb > mydb=> CREATE FUNCTION MONDAY(timestamp) RETURNS DATE AS ' > DECLARE > var1 date; > BEGIN > select into var1 to_date($1::date-(case when extract(DOW from > timestamp $1) = 0 then 6 else (extract(DOW from timestamp $1)-1) end)); > RETURN var1; > END' > language 'plpgsql'; > > CREATE > mydb=> select MONDAY('now'::timestamp); > NOTICE: Error occurred while executing PL/pgSQL function MONDAY > NOTICE: line 4 at select into variables > ERROR: parser: parse error at or near "$2" > mydb=> \q > > But I've not inserted any $2 there. > I've rewritten the same function in other ways but I've got the same error. > Something like the following works (as Richard already pointed out): CREATE OR REPLACE FUNCTION MONDAY(timestamp) RETURNS DATE AS 'DECLARE ts_param ALIAS FOR $1; var1 date;BEGIN select intovar1 to_date(ts_param::date- (case when extract(DOW from ts_param) = 0 then 6 else (extract(DOW from ts_param)-1) end),''DD'');RETURN var1;END' language 'plpgsql'; Me personally would prefer another approach: CREATE OR REPLACE FUNCTION MONDAY(timestamp) RETURNS DATE AS 'DECLARE ts_param ALIAS FOR $1; var1 date; var2 double precision;BEGINvar2 := extract(DOW from ts_param); IF var2 = 0 THEN var2 := 6; ELSE var2 := var2 - 1; END IF; var1 := to_date(ts_param::date- var2,''DD'');RETURN var1;END' language 'plpgsql'; because it's easier to read, but that's only a matter of taste I suppose. Regards, Christoph