Re: PL/SQL trouble

From: Christoph Haller <ch(at)rodos(dot)fzk(dot)de>
To: nonsolosoft(at)diff(dot)org
Cc: pgsql-sql(at)postgresql(dot)org
Subject: Re: PL/SQL trouble
Date: 2002-11-26 11:55:36
Message-ID: 3DE36138.2E8F24FF@rodos.fzk.de
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-sql

> 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 into var1 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;
BEGIN
var2 := 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

Browse pgsql-sql by date

  From Date Subject
Next Message Albrecht Berger 2002-11-26 12:55:51 Inheritance in SQL99 ?
Previous Message Richard Huxton 2002-11-26 10:51:18 Re: PL/SQL trouble