From 06ed133b347820f19d1186da281be56c45cbefc6 Mon Sep 17 00:00:00 2001 From: Carlos Ruiz Date: Fri, 30 May 2014 11:06:07 -0500 Subject: [PATCH] IDEMPIERE-1856 Amount in database functions and views are hardcoded to round to 2 decimal points --- .../oracle/functions/C_Invoice_Discount.sql | 9 +- .../functions/C_Invoice_Discount.sql | 7 +- .../oracle/201405301104_IDEMPIERE-1856.sql | 79 +++++++++++++++++ .../201405301104_IDEMPIERE-1856.sql | 86 +++++++++++++++++++ 4 files changed, 174 insertions(+), 7 deletions(-) create mode 100644 migration/i2.0z/oracle/201405301104_IDEMPIERE-1856.sql create mode 100644 migration/i2.0z/postgresql/201405301104_IDEMPIERE-1856.sql diff --git a/db/ddlutils/oracle/functions/C_Invoice_Discount.sql b/db/ddlutils/oracle/functions/C_Invoice_Discount.sql index 797ae2dc48..81844857e8 100644 --- a/db/ddlutils/oracle/functions/C_Invoice_Discount.sql +++ b/db/ddlutils/oracle/functions/C_Invoice_Discount.sql @@ -25,15 +25,16 @@ AS v_GrandTotal NUMBER; v_TotalLines NUMBER; v_C_PaymentTerm_ID NUMBER(10); + v_C_Currency_ID NUMBER(10); v_DocDate DATE; v_PayDate DATE := SysDate; v_IsPayScheduleValid CHAR(1); BEGIN SELECT ci.IsDiscountLineAmt, i.GrandTotal, i.TotalLines, - i.C_PaymentTerm_ID, i.DateInvoiced, i.IsPayScheduleValid + i.C_PaymentTerm_ID, i.DateInvoiced, i.IsPayScheduleValid, C_Currency_ID INTO v_IsDiscountLineAmt, v_GrandTotal, v_TotalLines, - v_C_PaymentTerm_ID, v_DocDate, v_IsPayScheduleValid + v_C_PaymentTerm_ID, v_DocDate, v_IsPayScheduleValid, v_C_Currency_ID FROM AD_ClientInfo ci, C_Invoice i WHERE ci.AD_Client_ID=i.AD_Client_ID AND i.C_Invoice_ID=p_C_Invoice_ID; @@ -64,11 +65,11 @@ BEGIN END IF; -- return discount amount - RETURN paymentTermDiscount (v_Amount, 0, v_C_PaymentTerm_ID, v_DocDate, p_PayDate); + RETURN paymentTermDiscount (v_Amount, v_C_Currency_ID, v_C_PaymentTerm_ID, v_DocDate, p_PayDate); -- Most likely if invoice not found EXCEPTION WHEN OTHERS THEN RETURN NULL; END invoiceDiscount; -/ \ No newline at end of file +/ diff --git a/db/ddlutils/postgresql/functions/C_Invoice_Discount.sql b/db/ddlutils/postgresql/functions/C_Invoice_Discount.sql index b7f83bdd96..f5bf2adff2 100644 --- a/db/ddlutils/postgresql/functions/C_Invoice_Discount.sql +++ b/db/ddlutils/postgresql/functions/C_Invoice_Discount.sql @@ -29,15 +29,16 @@ DECLARE v_GrandTotal NUMERIC; v_TotalLines NUMERIC; v_C_PaymentTerm_ID NUMERIC(10); + v_C_Currency_ID NUMERIC(10); v_DocDate timestamp with time zone; v_PayDate timestamp with time zone := now(); v_IsPayScheduleValid CHAR(1); BEGIN SELECT ci.IsDiscountLineAmt, i.GrandTotal, i.TotalLines, - i.C_PaymentTerm_ID, i.DateInvoiced, i.IsPayScheduleValid + i.C_PaymentTerm_ID, i.DateInvoiced, i.IsPayScheduleValid, C_Currency_ID INTO v_IsDiscountLineAmt, v_GrandTotal, v_TotalLines, - v_C_PaymentTerm_ID, v_DocDate, v_IsPayScheduleValid + v_C_PaymentTerm_ID, v_DocDate, v_IsPayScheduleValid, v_C_Currency_ID FROM AD_ClientInfo ci, C_Invoice i WHERE ci.AD_Client_ID=i.AD_Client_ID AND i.C_Invoice_ID=p_C_Invoice_ID; @@ -69,7 +70,7 @@ BEGIN END IF; -- return discount amount - RETURN paymentTermDiscount (v_Amount, 0, v_C_PaymentTerm_ID, v_DocDate, p_PayDate); + RETURN paymentTermDiscount (v_Amount, v_C_Currency_ID, v_C_PaymentTerm_ID, v_DocDate, p_PayDate); -- Most likely if invoice not found EXCEPTION diff --git a/migration/i2.0z/oracle/201405301104_IDEMPIERE-1856.sql b/migration/i2.0z/oracle/201405301104_IDEMPIERE-1856.sql new file mode 100644 index 0000000000..d2c06d22c2 --- /dev/null +++ b/migration/i2.0z/oracle/201405301104_IDEMPIERE-1856.sql @@ -0,0 +1,79 @@ +CREATE OR REPLACE FUNCTION invoiceDiscount +( + p_C_Invoice_ID IN NUMBER, + p_PayDate IN DATE, + p_C_InvoicePaySchedule_ID IN NUMBER +) +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_Invoice_Discount.sql,v 1.1 2006/04/21 17:51:58 jjanke Exp $ + *** + * Title: Calculate Payment Discount Amount + * Description: + * - Calculate discountable amount (i.e. with or without tax) + * - Calculate and return payment discount + ************************************************************************/ +AS + v_Amount NUMBER; + v_IsDiscountLineAmt CHAR(1); + v_GrandTotal NUMBER; + v_TotalLines NUMBER; + v_C_PaymentTerm_ID NUMBER(10); + v_C_Currency_ID NUMBER(10); + v_DocDate DATE; + v_PayDate DATE := SysDate; + v_IsPayScheduleValid CHAR(1); + +BEGIN + SELECT ci.IsDiscountLineAmt, i.GrandTotal, i.TotalLines, + i.C_PaymentTerm_ID, i.DateInvoiced, i.IsPayScheduleValid, C_Currency_ID + INTO v_IsDiscountLineAmt, v_GrandTotal, v_TotalLines, + v_C_PaymentTerm_ID, v_DocDate, v_IsPayScheduleValid, v_C_Currency_ID + FROM AD_ClientInfo ci, C_Invoice i + WHERE ci.AD_Client_ID=i.AD_Client_ID + AND i.C_Invoice_ID=p_C_Invoice_ID; + -- What Amount is the Discount Base? + IF (v_IsDiscountLineAmt = 'Y') THEN + v_Amount := v_TotalLines; + ELSE + v_Amount := v_GrandTotal; + END IF; + + -- Anything to discount? + IF (v_Amount = 0) THEN + RETURN 0; + END IF; + IF (p_PayDate IS NOT NULL) THEN + v_PayDate := p_PayDate; + END IF; + + -- Valid Payment Schedule + IF (v_IsPayScheduleValid='Y' AND p_C_InvoicePaySchedule_ID > 0) THEN + SELECT COALESCE(MAX(DiscountAmt),0) + INTO v_Amount + FROM C_InvoicePaySchedule + WHERE C_InvoicePaySchedule_ID=p_C_InvoicePaySchedule_ID + AND DiscountDate <= v_PayDate; + -- + RETURN v_Amount; + END IF; + + -- return discount amount + RETURN paymentTermDiscount (v_Amount, v_C_Currency_ID, v_C_PaymentTerm_ID, v_DocDate, p_PayDate); + +-- Most likely if invoice not found +EXCEPTION + WHEN OTHERS THEN + RETURN NULL; +END invoiceDiscount; +/ + +SELECT register_migration_script('201405301104_IDEMPIERE-1856.sql') FROM dual +; + diff --git a/migration/i2.0z/postgresql/201405301104_IDEMPIERE-1856.sql b/migration/i2.0z/postgresql/201405301104_IDEMPIERE-1856.sql new file mode 100644 index 0000000000..5b5850aa8d --- /dev/null +++ b/migration/i2.0z/postgresql/201405301104_IDEMPIERE-1856.sql @@ -0,0 +1,86 @@ +CREATE OR REPLACE FUNCTION invoiceDiscount +( + p_C_Invoice_ID NUMERIC, + p_paydate timestamp with time zone, + p_C_InvoicePaySchedule_ID NUMERIC +) +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 Payment Discount Amount + * Description: + * - Calculate discountable amount (i.e. with or without tax) + * - Calculate and return payment discount + * Test: + * select invoiceDiscount(109, now(), 103) from ad_system; => 0 + ************************************************************************/ +DECLARE + v_Amount NUMERIC; + v_IsDiscountLineAmt CHAR(1); + v_GrandTotal NUMERIC; + v_TotalLines NUMERIC; + v_C_PaymentTerm_ID NUMERIC(10); + v_C_Currency_ID NUMERIC(10); + v_DocDate timestamp with time zone; + v_PayDate timestamp with time zone := now(); + v_IsPayScheduleValid CHAR(1); + +BEGIN + SELECT ci.IsDiscountLineAmt, i.GrandTotal, i.TotalLines, + i.C_PaymentTerm_ID, i.DateInvoiced, i.IsPayScheduleValid, C_Currency_ID + INTO v_IsDiscountLineAmt, v_GrandTotal, v_TotalLines, + v_C_PaymentTerm_ID, v_DocDate, v_IsPayScheduleValid, v_C_Currency_ID + FROM AD_ClientInfo ci, C_Invoice i + WHERE ci.AD_Client_ID=i.AD_Client_ID + AND i.C_Invoice_ID=p_C_Invoice_ID; + + -- What Amount is the Discount Base? + IF (v_IsDiscountLineAmt = 'Y') THEN + v_Amount := v_TotalLines; + ELSE + v_Amount := v_GrandTotal; + END IF; + + -- Anything to discount? + IF (v_Amount = 0) THEN + RETURN 0; + END IF; + IF (p_PayDate IS NOT NULL) THEN + v_PayDate := p_PayDate; + END IF; + + -- Valid Payment Schedule + IF (v_IsPayScheduleValid='Y' AND p_C_InvoicePaySchedule_ID > 0) THEN + SELECT COALESCE(MAX(DiscountAmt),0) + INTO v_Amount + FROM C_InvoicePaySchedule + WHERE C_InvoicePaySchedule_ID=p_C_InvoicePaySchedule_ID + AND DiscountDate <= v_PayDate; + -- + RETURN v_Amount; + END IF; + + -- return discount amount + RETURN paymentTermDiscount (v_Amount, v_C_Currency_ID, v_C_PaymentTerm_ID, v_DocDate, p_PayDate); + +-- Most likely if invoice not found +EXCEPTION + WHEN OTHERS THEN + RETURN NULL; +END; + +$body$ LANGUAGE plpgsql; + + +SELECT register_migration_script('201405301104_IDEMPIERE-1856.sql') FROM dual +; +