From b0e6e1552a2ce431dd3af14cdb6bce0d089aa17b Mon Sep 17 00:00:00 2001 From: Heng Sin Low Date: Fri, 26 Jan 2007 09:54:54 +0000 Subject: [PATCH] * Implement trunc in pl/pgsql * Implement additional functions that is using the plsql version even when running on oracle sqlj * Modified timestamp manipulation function to return date to align with the oracle convention --- db/ddlutils/postgresql/functions/addDays.sql | 35 +++++++++ .../postgresql/functions/daysBetween.sql | 28 +++++++ db/ddlutils/postgresql/functions/firstOf.sql | 74 ++++++++++--------- db/ddlutils/postgresql/functions/getDate.sql | 6 ++ db/ddlutils/postgresql/functions/trunc.sql | 53 +++++++++++++ 5 files changed, 160 insertions(+), 36 deletions(-) create mode 100644 db/ddlutils/postgresql/functions/addDays.sql create mode 100644 db/ddlutils/postgresql/functions/daysBetween.sql create mode 100644 db/ddlutils/postgresql/functions/getDate.sql create mode 100644 db/ddlutils/postgresql/functions/trunc.sql diff --git a/db/ddlutils/postgresql/functions/addDays.sql b/db/ddlutils/postgresql/functions/addDays.sql new file mode 100644 index 0000000000..4692410be8 --- /dev/null +++ b/db/ddlutils/postgresql/functions/addDays.sql @@ -0,0 +1,35 @@ +/* +*This file is part of Adempiere ERP Bazaar +*http://www.adempiere.org +* +*Copyright (C) 2007 Low Heng Sin +*Copyright (C) 1999-2006 ComPiere, inc +* +*This program is free software; you can redistribute it and/or +*modify it under the terms of the GNU General Public License +*as published by the Free Software Foundation; either version 2 +*of the License, or (at your option) any later version. +* +*This program is distributed in the hope that it will be useful, +*but WITHOUT ANY WARRANTY; without even the implied warranty of +*MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the +*GNU General Public License for more details. +* +*You should have received a copy of the GNU General Public License +*along with this program; if not, write to the Free Software +*Foundation, Inc., 51 Franklin Street, Fifth Floor, Boston, MA 02110-1301, USA.of +*/ + +CREATE OR REPLACE FUNCTION addDays(datetime TIMESTAMP WITH TIME ZONE, days Numeric) +RETURNS DATE AS $$ +BEGIN + RETURN CAST(datetime AS DATE) + days; +END; +$$ LANGUAGE plpgsql; + +CREATE OR REPLACE FUNCTION subtractdays (day TIMESTAMP WITH TIME ZONE, days NUMERIC) +RETURNS TIMESTAMP WITH TIME ZONE AS $$ +BEGIN + RETURN addDays(day,(days * -1)); +END; +$$ LANGUAGE plpgsql; \ No newline at end of file diff --git a/db/ddlutils/postgresql/functions/daysBetween.sql b/db/ddlutils/postgresql/functions/daysBetween.sql new file mode 100644 index 0000000000..3bdbf7fc96 --- /dev/null +++ b/db/ddlutils/postgresql/functions/daysBetween.sql @@ -0,0 +1,28 @@ +/* +*This file is part of Adempiere ERP Bazaar +*http://www.adempiere.org +* +*Copyright (C) 2007 Low Heng Sin +*Copyright (C) 1999-2006 ComPiere, inc +* +*This program is free software; you can redistribute it and/or +*modify it under the terms of the GNU General Public License +*as published by the Free Software Foundation; either version 2 +*of the License, or (at your option) any later version. +* +*This program is distributed in the hope that it will be useful, +*but WITHOUT ANY WARRANTY; without even the implied warranty of +*MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the +*GNU General Public License for more details. +* +*You should have received a copy of the GNU General Public License +*along with this program; if not, write to the Free Software +*Foundation, Inc., 51 Franklin Street, Fifth Floor, Boston, MA 02110-1301, USA.of +*/ + +CREATE OR REPLACE FUNCTION daysBetween(p_date1 TIMESTAMP WITH TIME ZONE, p_date2 TIMESTAMP WITH TIME ZONE) +RETURNS INTEGER AS $$ +BEGIN + RETURN CAST(p_date1 AS DATE) - CAST(p_date2 as DATE); +END; +$$ LANGUAGE plpgsql; diff --git a/db/ddlutils/postgresql/functions/firstOf.sql b/db/ddlutils/postgresql/functions/firstOf.sql index c3ee8af88e..37a901d37e 100644 --- a/db/ddlutils/postgresql/functions/firstOf.sql +++ b/db/ddlutils/postgresql/functions/firstOf.sql @@ -26,45 +26,47 @@ SET search_path = adempiere, pg_catalog; CREATE OR REPLACE FUNCTION firstOf ( IN TIMESTAMP WITH TIME ZONE, -- $1 date IN VARCHAR -- $2 part of date -) RETURNS TIMESTAMP WITH TIME ZONE AS +) RETURNS DATE AS $$ DECLARE datepart VARCHAR; +datetime TIMESTAMP WITH TIME ZONE; BEGIN -datepart = $2; -IF $2 IN ('') THEN -datepart = 'millennium'; -ELSEIF $2 IN ('') THEN -datepart = 'century'; -ELSEIF $2 IN ('') THEN -datepart = 'decade'; -ELSEIF $2 IN ('IYYY','IY','I') THEN -datepart = 'year'; -ELSEIF $2 IN ('SYYYY','YYYY','YEAR','SYEAR','YYY','YY','Y') THEN -datepart = 'year'; -ELSEIF $2 IN ('Q') THEN -datepart = 'quarter'; -ELSEIF $2 IN ('MONTH','MON','MM','RM') THEN -datepart = 'month'; -ELSEIF $2 IN ('IW') THEN -datepart = 'week'; -ELSEIF $2 IN ('W') THEN -datepart = 'week'; -ELSEIF $2 IN ('DDD','DD','J') THEN -datepart = 'day'; -ELSEIF $2 IN ('DAY','DY','D') THEN -datepart = 'day'; -ELSEIF $2 IN ('HH','HH12','HH24') THEN -datepart = 'hour'; -ELSEIF $2 IN ('MI') THEN -datepart = 'minute'; -ELSEIF $2 IN ('') THEN -datepart = 'second'; -ELSEIF $2 IN ('') THEN -datepart = 'milliseconds'; -ELSEIF $2 IN ('') THEN -datepart = 'microseconds'; -END IF; -RETURN date_trunc(datepart, CAST($1 AS DATE)); + datepart = $2; + IF $2 IN ('') THEN + datepart = 'millennium'; + ELSEIF $2 IN ('') THEN + datepart = 'century'; + ELSEIF $2 IN ('') THEN + datepart = 'decade'; + ELSEIF $2 IN ('IYYY','IY','I') THEN + datepart = 'year'; + ELSEIF $2 IN ('SYYYY','YYYY','YEAR','SYEAR','YYY','YY','Y') THEN + datepart = 'year'; + ELSEIF $2 IN ('Q') THEN + datepart = 'quarter'; + ELSEIF $2 IN ('MONTH','MON','MM','RM') THEN + datepart = 'month'; + ELSEIF $2 IN ('IW') THEN + datepart = 'week'; + ELSEIF $2 IN ('W') THEN + datepart = 'week'; + ELSEIF $2 IN ('DDD','DD','J') THEN + datepart = 'day'; + ELSEIF $2 IN ('DAY','DY','D') THEN + datepart = 'day'; + ELSEIF $2 IN ('HH','HH12','HH24') THEN + datepart = 'hour'; + ELSEIF $2 IN ('MI') THEN + datepart = 'minute'; + ELSEIF $2 IN ('') THEN + datepart = 'second'; + ELSEIF $2 IN ('') THEN + datepart = 'milliseconds'; + ELSEIF $2 IN ('') THEN + datepart = 'microseconds'; + END IF; + datetime = date_trunc(datepart, $1); +RETURN cast(datetime as date); END; $$ LANGUAGE plpgsql; diff --git a/db/ddlutils/postgresql/functions/getDate.sql b/db/ddlutils/postgresql/functions/getDate.sql new file mode 100644 index 0000000000..22fa333ba8 --- /dev/null +++ b/db/ddlutils/postgresql/functions/getDate.sql @@ -0,0 +1,6 @@ +CREATE OR REPLACE FUNCTION getDate() +RETURNS TIMESTAMP WITH TIME ZONE AS $$ +BEGIN + RETURN now(); +END; +$$ LANGUAGE plpgsql VOLATILE; diff --git a/db/ddlutils/postgresql/functions/trunc.sql b/db/ddlutils/postgresql/functions/trunc.sql new file mode 100644 index 0000000000..27d5a3c117 --- /dev/null +++ b/db/ddlutils/postgresql/functions/trunc.sql @@ -0,0 +1,53 @@ +/* +*This file is part of Adempiere ERP Bazaar +*http://www.adempiere.org +* +*Copyright (C) 2007 Low Heng Sin +*Copyright (C) 1999-2006 ComPiere, inc +* +*This program is free software; you can redistribute it and/or +*modify it under the terms of the GNU General Public License +*as published by the Free Software Foundation; either version 2 +*of the License, or (at your option) any later version. +* +*This program is distributed in the hope that it will be useful, +*but WITHOUT ANY WARRANTY; without even the implied warranty of +*MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the +*GNU General Public License for more details. +* +*You should have received a copy of the GNU General Public License +*along with this program; if not, write to the Free Software +*Foundation, Inc., 51 Franklin Street, Fifth Floor, Boston, MA 02110-1301, USA.of +*/ +CREATE OR REPLACE FUNCTION trunc(datetime TIMESTAMP WITH TIME ZONE) +RETURNS DATE AS $$ +BEGIN + RETURN CAST(datetime AS DATE); +END; +$$ LANGUAGE plpgsql; + +CREATE OR REPLACE FUNCTION trunc(datetime TIMESTAMP WITH TIME ZONE, format varchar) +RETURNS DATE AS $$ +BEGIN + IF format = 'Q' THEN + RETURN CAST(DATE_Trunc('quarter',datetime) as DATE); + ELSIF format = 'Y' THEN + RETURN CAST(DATE_Trunc('year',datetime) as DATE); + ELSIF format = 'MM' THEN + RETURN CAST(DATE_Trunc('month',datetime) as DATE); + ELSIF format = 'DD' THEN + RETURN CAST(DATE_Trunc('day',datetime) as DATE); + ELSIF format = 'DY' THEN + RETURN CAST(DATE_Trunc('day',datetime) as DATE); + ELSE + RETURN CAST(datetime AS DATE); + END IF; +END; +$$ LANGUAGE plpgsql; + +CREATE OR REPLACE FUNCTION trunc(i INTERVAL) +RETURNS INTEGER AS $$ +BEGIN + RETURN EXTRACT(DAY FROM i); +END; +$$ LANGUAGE plpgsql; \ No newline at end of file