From 4d8f66dea709f78bf05166002be68bbcd9b24731 Mon Sep 17 00:00:00 2001 From: Carlos Ruiz Date: Wed, 25 Mar 2009 05:02:55 +0000 Subject: [PATCH] Integrate fix for [2710889] - Function PaymentTermDueDate: Cast Error Contributed by Ricardo (ralexsander) --- .../postgresql/functions/Add_Months.sql | 13 +++++ .../functions/C_PaymentTerm_DueDate.sql | 18 +++---- .../oracle/441_BF2710889_Add_Months.sql | 1 + .../442_BF2710889_PaymentTermDueDate.sql | 1 + .../postgresql/441_BF2710889_Add_Months.sql | 13 +++++ .../442_BF2710889_PaymentTermDueDate.sql | 49 +++++++++++++++++++ 6 files changed, 83 insertions(+), 12 deletions(-) create mode 100644 db/ddlutils/postgresql/functions/Add_Months.sql create mode 100644 migration/353a-trunk/oracle/441_BF2710889_Add_Months.sql create mode 100644 migration/353a-trunk/oracle/442_BF2710889_PaymentTermDueDate.sql create mode 100644 migration/353a-trunk/postgresql/441_BF2710889_Add_Months.sql create mode 100644 migration/353a-trunk/postgresql/442_BF2710889_PaymentTermDueDate.sql diff --git a/db/ddlutils/postgresql/functions/Add_Months.sql b/db/ddlutils/postgresql/functions/Add_Months.sql new file mode 100644 index 0000000000..aba7aa2781 --- /dev/null +++ b/db/ddlutils/postgresql/functions/Add_Months.sql @@ -0,0 +1,13 @@ +CREATE OR REPLACE FUNCTION add_months (in datetime timestamptz, in months numeric) RETURNS date AS +$BODY$ +declare duration varchar; +BEGIN + if datetime is null or months is null then + return null; + end if; + duration = months || ' month'; + return cast(datetime + cast(duration as interval) as date); +END; +$BODY$ +LANGUAGE 'plpgsql' +; diff --git a/db/ddlutils/postgresql/functions/C_PaymentTerm_DueDate.sql b/db/ddlutils/postgresql/functions/C_PaymentTerm_DueDate.sql index e03c8c7cb5..3e6384aaef 100644 --- a/db/ddlutils/postgresql/functions/C_PaymentTerm_DueDate.sql +++ b/db/ddlutils/postgresql/functions/C_PaymentTerm_DueDate.sql @@ -1,9 +1,5 @@ -create or replace FUNCTION paymenttermDueDate -( - PaymentTerm_ID IN NUMERIC, - DocDate IN timestamp with time zone -) -RETURNS timestamp with time zone AS $body$ +CREATE OR REPLACE FUNCTION "adempiere"."paymenttermduedate" (in paymentterm_id numeric, in docdate timestamptz) RETURNS timestamptz AS +$BODY$ /************************************************************************* * The contents of this file are subject to the Compiere License. You may * obtain a copy of the License at http://www.compiere.org/license.html @@ -36,7 +32,7 @@ BEGIN -- Due 15th of following month IF (p.IsDueFixed = 'Y') THEN FirstDay := TRUNC(DocDate, 'MM'); - NoDays := TRUNC(DocDate) - FirstDay; + NoDays := EXTRACT(epoch FROM TRUNC(DocDate) - FirstDay); DueDate := FirstDay + (p.FixMonthDay-1); -- starting on 1st DueDate := ADD_MONTHS(DueDate, p.FixMonthOffset); IF (NoDays > p.FixMonthCutoff) THEN @@ -46,10 +42,8 @@ BEGIN DueDate := TRUNC(DocDate) + p.NetDays; END IF; END LOOP; - RETURN DueDate; END; - -$body$ LANGUAGE plpgsql; - - +$BODY$ +LANGUAGE 'plpgsql' +; diff --git a/migration/353a-trunk/oracle/441_BF2710889_Add_Months.sql b/migration/353a-trunk/oracle/441_BF2710889_Add_Months.sql new file mode 100644 index 0000000000..8d61dca7e9 --- /dev/null +++ b/migration/353a-trunk/oracle/441_BF2710889_Add_Months.sql @@ -0,0 +1 @@ +-- just for postgresql diff --git a/migration/353a-trunk/oracle/442_BF2710889_PaymentTermDueDate.sql b/migration/353a-trunk/oracle/442_BF2710889_PaymentTermDueDate.sql new file mode 100644 index 0000000000..8d61dca7e9 --- /dev/null +++ b/migration/353a-trunk/oracle/442_BF2710889_PaymentTermDueDate.sql @@ -0,0 +1 @@ +-- just for postgresql diff --git a/migration/353a-trunk/postgresql/441_BF2710889_Add_Months.sql b/migration/353a-trunk/postgresql/441_BF2710889_Add_Months.sql new file mode 100644 index 0000000000..aba7aa2781 --- /dev/null +++ b/migration/353a-trunk/postgresql/441_BF2710889_Add_Months.sql @@ -0,0 +1,13 @@ +CREATE OR REPLACE FUNCTION add_months (in datetime timestamptz, in months numeric) RETURNS date AS +$BODY$ +declare duration varchar; +BEGIN + if datetime is null or months is null then + return null; + end if; + duration = months || ' month'; + return cast(datetime + cast(duration as interval) as date); +END; +$BODY$ +LANGUAGE 'plpgsql' +; diff --git a/migration/353a-trunk/postgresql/442_BF2710889_PaymentTermDueDate.sql b/migration/353a-trunk/postgresql/442_BF2710889_PaymentTermDueDate.sql new file mode 100644 index 0000000000..3e6384aaef --- /dev/null +++ b/migration/353a-trunk/postgresql/442_BF2710889_PaymentTermDueDate.sql @@ -0,0 +1,49 @@ +CREATE OR REPLACE FUNCTION "adempiere"."paymenttermduedate" (in paymentterm_id numeric, in docdate timestamptz) RETURNS timestamptz AS +$BODY$ +/************************************************************************* + * The contents of this file are subject to the Compiere License. You may + * obtain a copy of the License at http://www.compiere.org/license.html + * Software is on an "AS IS" basis, WITHOUT WARRANTY OF ANY KIND, either + * express or implied. See the License for details. Code: Compiere ERP+CRM + * Copyright (C) 1999-2001 Jorg Janke, ComPiere, Inc. All Rights Reserved. + * + * converted to postgreSQL by Karsten Thiemann (Schaeffer AG), + * kthiemann@adempiere.org + ************************************************************************* + * Title: Get Due timestamp with time zone + * Description: + * Returns the due timestamp with time zone + * Test: + * select paymenttermDueDate(106, now()) from Test; => now()+30 days + ************************************************************************/ +DECLARE + Days NUMERIC := 0; + DueDate timestamp with time zone := TRUNC(DocDate); + -- + FirstDay timestamp with time zone; + NoDays NUMERIC; + p RECORD; +BEGIN + FOR p IN + SELECT * + FROM C_PaymentTerm + WHERE C_PaymentTerm_ID = PaymentTerm_ID + LOOP -- for convineance only + -- Due 15th of following month + IF (p.IsDueFixed = 'Y') THEN + FirstDay := TRUNC(DocDate, 'MM'); + NoDays := EXTRACT(epoch FROM TRUNC(DocDate) - FirstDay); + DueDate := FirstDay + (p.FixMonthDay-1); -- starting on 1st + DueDate := ADD_MONTHS(DueDate, p.FixMonthOffset); + IF (NoDays > p.FixMonthCutoff) THEN + DueDate := ADD_MONTHS(DueDate, 1); + END IF; + ELSE + DueDate := TRUNC(DocDate) + p.NetDays; + END IF; + END LOOP; + RETURN DueDate; +END; +$BODY$ +LANGUAGE 'plpgsql' +;