diff --git a/db/ddlutils/oracle/functions/C_PaymentTerm_Discount.sql b/db/ddlutils/oracle/functions/C_PaymentTerm_Discount.sql index 3eca08f287..c403c42a8b 100644 --- a/db/ddlutils/oracle/functions/C_PaymentTerm_Discount.sql +++ b/db/ddlutils/oracle/functions/C_PaymentTerm_Discount.sql @@ -25,6 +25,7 @@ RETURN NUMBER AS v_Precision NUMBER := 0; + v_Currency NUMBER := 0; v_Min NUMBER := 0; Discount NUMBER := 0; CURSOR Cur_PT IS @@ -36,10 +37,20 @@ AS Add1Date NUMBER := 0; Add2Date NUMBER := 0; BEGIN + v_Currency := Currency_ID; + IF (v_Currency = 0) THEN + SELECT COALESCE(MAX(C_Currency_ID),0) + INTO v_Currency + FROM AD_ClientInfo ci, C_AcctSchema s, C_PaymentTerm pt + WHERE ci.AD_Client_ID = s.AD_Client_ID + AND ci.AD_Client_ID = pt.AD_Client_ID + AND pt.C_PaymentTerm_ID = PaymentTerm_ID; + END IF; + SELECT StdPrecision INTO v_Precision FROM C_Currency - WHERE C_Currency_ID = Currency_ID; + WHERE C_Currency_ID = v_Currency; SELECT POWER(1/10,v_Precision) INTO v_Min FROM DUAL; diff --git a/db/ddlutils/postgresql/functions/C_PaymentTerm_Discount.sql b/db/ddlutils/postgresql/functions/C_PaymentTerm_Discount.sql index 5fcbb88256..6fdc1498f0 100644 --- a/db/ddlutils/postgresql/functions/C_PaymentTerm_Discount.sql +++ b/db/ddlutils/postgresql/functions/C_PaymentTerm_Discount.sql @@ -26,6 +26,7 @@ RETURNS NUMERIC AS $body$ DECLARE v_Precision NUMERIC := 0; + v_Currency NUMERIC := 0; v_Min NUMERIC := 0; Discount NUMERIC := 0; Discount1Date timestamp with time zone; @@ -34,10 +35,20 @@ DECLARE Add2Date NUMERIC := 0; p RECORD; BEGIN + v_Currency := Currency_ID; + IF (v_Currency = 0) THEN + SELECT COALESCE(MAX(C_Currency_ID),0) + INTO v_Currency + FROM AD_ClientInfo ci, C_AcctSchema s, C_PaymentTerm pt + WHERE ci.AD_Client_ID = s.AD_Client_ID + AND ci.AD_Client_ID = pt.AD_Client_ID + AND pt.C_PaymentTerm_ID = PaymentTerm_ID; + END IF; + SELECT StdPrecision INTO v_Precision FROM C_Currency - WHERE C_Currency_ID = Currency_ID; + WHERE C_Currency_ID = v_Currency; SELECT 1/10^v_Precision INTO v_Min; diff --git a/migration/i2.0z/oracle/201406061832_IDEMPIERE-1856.sql b/migration/i2.0z/oracle/201406061832_IDEMPIERE-1856.sql new file mode 100644 index 0000000000..f18c35efb2 --- /dev/null +++ b/migration/i2.0z/oracle/201406061832_IDEMPIERE-1856.sql @@ -0,0 +1,100 @@ +-- June 6, 2014 18:32:00 PM SGT +-- IDEMPIERE-1856 Amount in database functions and views are hardcoded to round to 2 decimal points + +CREATE OR REPLACE FUNCTION paymentTermDiscount +( + Amount IN NUMBER, + Currency_ID IN NUMBER, + PaymentTerm_ID IN NUMBER, + DocDate IN DATE, + PayDate IN DATE +) +RETURN NUMBER +/************************************************************************* + * 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. + ************************************************************************* + * $Id: C_PaymentTerm_Discount.sql,v 1.1 2006/04/21 17:51:58 jjanke Exp $ + *** + * Title: Calculate Discount + * Description: + * Calculate the allowable Discount Amount of the Payment Term + * + * Test: SELECT C_PaymentTerm_Discount(17777, 103, '10-DEC-1999') FROM DUAL + ************************************************************************/ + +AS + v_Precision NUMBER := 0; + v_Currency NUMBER := 0; + v_Min NUMBER := 0; + Discount NUMBER := 0; + CURSOR Cur_PT IS + SELECT * + FROM C_PaymentTerm + WHERE C_PaymentTerm_ID = PaymentTerm_ID; + Discount1Date DATE; + Discount2Date DATE; + Add1Date NUMBER := 0; + Add2Date NUMBER := 0; +BEGIN + v_Currency := Currency_ID; + IF (v_Currency = 0) THEN + SELECT COALESCE(MAX(C_Currency_ID),0) + INTO v_Currency + FROM AD_ClientInfo ci, C_AcctSchema s, C_PaymentTerm pt + WHERE ci.AD_Client_ID = s.AD_Client_ID + AND ci.AD_Client_ID = pt.AD_Client_ID + AND pt.C_PaymentTerm_ID = PaymentTerm_ID; + END IF; + + SELECT StdPrecision + INTO v_Precision + FROM C_Currency + WHERE C_Currency_ID = v_Currency; + + SELECT POWER(1/10,v_Precision) INTO v_Min FROM DUAL; + + -- No Data - No Discount + IF (Amount IS NULL OR PaymentTerm_ID IS NULL OR DocDate IS NULL) THEN + RETURN 0; + END IF; + + FOR p IN Cur_PT LOOP -- for convineance only +-- DBMS_OUTPUT.PUT_LINE(p.Name || ' - Doc = ' || TO_CHAR(DocDate)); + Discount1Date := TRUNC(DocDate + p.DiscountDays + p.GraceDays); + Discount2Date := TRUNC(DocDate + p.DiscountDays2 + p.GraceDays); + + -- Next Business Day + IF (p.IsNextBusinessDay='Y') THEN + Discount1Date := nextBusinessDay(Discount1Date, p.AD_Client_ID); + Discount2Date := nextBusinessDay(Discount2Date, p.AD_Client_ID); + END IF; + + -- Discount 1 + IF (Discount1Date >= TRUNC(PayDate)) THEN +-- DBMS_OUTPUT.PUT_LINE('Discount 1 ' || TO_CHAR(Discount1Date) || ' ' || p.Discount); + Discount := Amount * p.Discount / 100; + -- Discount 2 + ELSIF (Discount2Date >= TRUNC(PayDate)) THEN +-- DBMS_OUTPUT.PUT_LINE('Discount 2 ' || TO_CHAR(Discount2Date) || ' ' || p.Discount2); + Discount := Amount * p.Discount2 / 100; + END IF; + END LOOP; + + -- Ignore Rounding + IF (Discount > -v_Min AND Discount < v_Min) THEN + Discount := 0; + END IF; + + -- Round to currency precision + Discount := ROUND(COALESCE(Discount,0), v_Precision); + + RETURN Discount; +END paymentTermDiscount; +/ + +SELECT register_migration_script('201406061832_IDEMPIERE-1856.sql') FROM dual +; \ No newline at end of file diff --git a/migration/i2.0z/postgresql/201406061832_IDEMPIERE-1856.sql b/migration/i2.0z/postgresql/201406061832_IDEMPIERE-1856.sql new file mode 100644 index 0000000000..806795278d --- /dev/null +++ b/migration/i2.0z/postgresql/201406061832_IDEMPIERE-1856.sql @@ -0,0 +1,100 @@ +-- June 6, 2014 18:32:00 PM SGT +-- IDEMPIERE-1856 Amount in database functions and views are hardcoded to round to 2 decimal points + +create or replace FUNCTION paymenttermDiscount +( + Amount NUMERIC, + Currency_ID NUMERIC, + PaymentTerm_ID NUMERIC, + DocDate timestamp with time zone, + PayDate timestamp with time zone +) +RETURNS NUMERIC 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: Calculate Discount + * Description: + * Calculate the allowable Discount Amount of the Payment Term + * + * Test: SELECT paymenttermDiscount(110, 103, 106, now(), now()) FROM TEST; => 2.20 + ************************************************************************/ + +DECLARE + v_Precision NUMERIC := 0; + v_Currency NUMERIC := 0; + v_Min NUMERIC := 0; + Discount NUMERIC := 0; + Discount1Date timestamp with time zone; + Discount2Date timestamp with time zone; + Add1Date NUMERIC := 0; + Add2Date NUMERIC := 0; + p RECORD; +BEGIN + v_Currency := Currency_ID; + IF (v_Currency = 0) THEN + SELECT COALESCE(MAX(C_Currency_ID),0) + INTO v_Currency + FROM AD_ClientInfo ci, C_AcctSchema s, C_PaymentTerm pt + WHERE ci.AD_Client_ID = s.AD_Client_ID + AND ci.AD_Client_ID = pt.AD_Client_ID + AND pt.C_PaymentTerm_ID = PaymentTerm_ID; + END IF; + + SELECT StdPrecision + INTO v_Precision + FROM C_Currency + WHERE C_Currency_ID = v_Currency; + + SELECT 1/10^v_Precision INTO v_Min; + + -- No Data - No Discount + IF (Amount IS NULL OR PaymentTerm_ID IS NULL OR DocDate IS NULL) THEN + RETURN 0; + END IF; + + FOR p IN + SELECT * + FROM C_PaymentTerm + WHERE C_PaymentTerm_ID = PaymentTerm_ID + LOOP -- for convineance only + Discount1Date := TRUNC(DocDate + p.DiscountDays + p.GraceDays); + Discount2Date := TRUNC(DocDate + p.DiscountDays2 + p.GraceDays); + + -- Next Business Day + IF (p.IsNextBusinessDay='Y') THEN + Discount1Date := nextBusinessDay(Discount1Date, p.AD_Client_ID); + Discount2Date := nextBusinessDay(Discount2Date, p.AD_Client_ID); + END IF; + + -- Discount 1 + IF (Discount1Date >= TRUNC(PayDate)) THEN + Discount := Amount * p.Discount / 100; + -- Discount 2 + ELSIF (Discount2Date >= TRUNC(PayDate)) THEN + Discount := Amount * p.Discount2 / 100; + END IF; + END LOOP; + + -- Ignore Rounding + IF (Discount > -v_Min AND Discount < v_Min) THEN + Discount := 0; + END IF; + + -- Round to currency precision + Discount := ROUND(COALESCE(Discount,0), v_Precision); + + RETURN Discount; +END; + +$body$ LANGUAGE plpgsql; + +SELECT register_migration_script('201406061832_IDEMPIERE-1856.sql') FROM dual +; \ No newline at end of file