From 19e13965de842a366a015662017319774318f5b6 Mon Sep 17 00:00:00 2001 From: Carlos Ruiz Date: Tue, 6 Mar 2007 02:17:23 +0000 Subject: [PATCH] Fix [ 1674561 ] Payment Allocation Error --- .../oracle/functions/C_Invoice_Open.sql | 22 ++-- migration/315-trunk/005_fix_INVOICEOPEN.sql | 115 ++++++++++++++++++ 2 files changed, 126 insertions(+), 11 deletions(-) create mode 100644 migration/315-trunk/005_fix_INVOICEOPEN.sql diff --git a/db/ddlutils/oracle/functions/C_Invoice_Open.sql b/db/ddlutils/oracle/functions/C_Invoice_Open.sql index 28bf8049ad..5ed99c97b2 100644 --- a/db/ddlutils/oracle/functions/C_Invoice_Open.sql +++ b/db/ddlutils/oracle/functions/C_Invoice_Open.sql @@ -6,14 +6,14 @@ CREATE OR REPLACE FUNCTION invoiceOpen 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 + * 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_Open.sql,v 1.1 2006/04/21 17:51:58 jjanke Exp $ *** - * Title: Calculate Open Item Amount in Invoice Currency + * Title: Calculate Open Item Amount in Invoice Currency * Description: * Add up total amount open for C_Invoice_ID if no split payment. * Grand Total minus Sum of Allocations in Invoice Currency @@ -41,8 +41,8 @@ AS v_Temp NUMBER := 0; -- CURSOR Cur_Alloc IS - SELECT a.AD_Client_ID, a.AD_Org_ID, - al.Amount, al.DiscountAmt, al.WriteOffAmt, + SELECT a.AD_Client_ID, a.AD_Org_ID, + al.Amount, al.DiscountAmt, al.WriteOffAmt, a.C_Currency_ID, a.DateTrx FROM C_AllocationLine al INNER JOIN C_AllocationHdr a ON (al.C_AllocationHdr_ID=a.C_AllocationHdr_ID) @@ -50,8 +50,8 @@ AS AND a.IsActive='Y'; -- CURSOR Cur_PaySchedule IS - SELECT C_InvoicePaySchedule_ID, DueAmt - FROM C_InvoicePaySchedule + SELECT C_InvoicePaySchedule_ID, DueAmt + FROM C_InvoicePaySchedule WHERE C_Invoice_ID = p_C_Invoice_ID AND IsValid='Y' ORDER BY DueDate; @@ -79,13 +79,13 @@ BEGIN a.C_Currency_ID, v_Currency_ID, a.DateTrx, null, a.AD_Client_ID, a.AD_Org_ID); DBMS_OUTPUT.PUT_LINE(' PaidAmt=' || v_PaidAmt || ', Allocation=' || v_Temp || ' * ' || v_MultiplierAP); END LOOP; - + -- Do we have a Payment Schedule ? IF (p_C_InvoicePaySchedule_ID > 0) THEN -- if not valid = lists invoice amount v_Remaining := v_PaidAmt; FOR s IN Cur_PaySchedule LOOP IF (s.C_InvoicePaySchedule_ID = p_C_InvoicePaySchedule_ID) THEN - v_TotalOpenAmt := (s.DueAmt*v_MultiplierCM) + v_Remaining; + v_TotalOpenAmt := (s.DueAmt*v_MultiplierCM) - v_Remaining; IF (s.DueAmt - v_Remaining < 0) THEN v_TotalOpenAmt := 0; END IF; @@ -107,9 +107,9 @@ BEGIN IF (v_TotalOpenAmt BETWEEN -0.00999 AND 0.00999) THEN v_TotalOpenAmt := 0; END IF; - + -- Round to penny v_TotalOpenAmt := ROUND(COALESCE(v_TotalOpenAmt,0), 2); RETURN v_TotalOpenAmt; END invoiceOpen; -/ \ No newline at end of file +/ diff --git a/migration/315-trunk/005_fix_INVOICEOPEN.sql b/migration/315-trunk/005_fix_INVOICEOPEN.sql new file mode 100644 index 0000000000..5ed99c97b2 --- /dev/null +++ b/migration/315-trunk/005_fix_INVOICEOPEN.sql @@ -0,0 +1,115 @@ +CREATE OR REPLACE FUNCTION invoiceOpen +( + p_C_Invoice_ID IN NUMBER, + 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_Open.sql,v 1.1 2006/04/21 17:51:58 jjanke Exp $ + *** + * Title: Calculate Open Item Amount in Invoice Currency + * Description: + * Add up total amount open for C_Invoice_ID if no split payment. + * Grand Total minus Sum of Allocations in Invoice Currency + * + * For Split Payments: + * Allocate Payments starting from first schedule. + +SELECT C_Invoice_Open (109) FROM DUAL; +SELECT C_Invoice_Open (109, null) FROM DUAL; +SELECT C_Invoice_Open (109, 11) FROM DUAL; +SELECT C_Invoice_Open (109, 102) FROM DUAL; +SELECT C_Invoice_Open (109, 103) FROM DUAL; +SELECT * FROM RV_OpenItem WHERE C_Invoice_ID=109; +SELECT C_InvoicePaySchedule_ID, DueAmt FROM C_InvoicePaySchedule WHERE C_Invoice_ID=109 ORDER BY DueDate; + + * Cannot be used for IsPaid as mutating + ************************************************************************/ +AS + v_Currency_ID NUMBER(10); + v_TotalOpenAmt NUMBER := 0; + v_PaidAmt NUMBER := 0; + v_Remaining NUMBER := 0; + v_MultiplierAP NUMBER := 0; + v_MultiplierCM NUMBER := 0; + v_Temp NUMBER := 0; + -- + CURSOR Cur_Alloc IS + SELECT a.AD_Client_ID, a.AD_Org_ID, + al.Amount, al.DiscountAmt, al.WriteOffAmt, + a.C_Currency_ID, a.DateTrx + FROM C_AllocationLine al + INNER JOIN C_AllocationHdr a ON (al.C_AllocationHdr_ID=a.C_AllocationHdr_ID) + WHERE al.C_Invoice_ID = p_C_Invoice_ID + AND a.IsActive='Y'; + -- + CURSOR Cur_PaySchedule IS + SELECT C_InvoicePaySchedule_ID, DueAmt + FROM C_InvoicePaySchedule + WHERE C_Invoice_ID = p_C_Invoice_ID + AND IsValid='Y' + ORDER BY DueDate; + +BEGIN + -- Get Currency + BEGIN + SELECT MAX(C_Currency_ID), SUM(GrandTotal), MAX(MultiplierAP), MAX(Multiplier) + INTO v_Currency_ID, v_TotalOpenAmt, v_MultiplierAP, v_MultiplierCM + FROM C_Invoice_v -- corrected for CM / Split Payment + WHERE C_Invoice_ID = p_C_Invoice_ID; + EXCEPTION -- Invoice in draft form + WHEN OTHERS THEN + DBMS_OUTPUT.PUT_LINE('InvoiceOpen - ' || SQLERRM); + RETURN NULL; + END; +-- DBMS_OUTPUT.PUT_LINE('== C_Invoice_ID=' || p_C_Invoice_ID || ', Total=' || v_TotalOpenAmt || ', AP=' || v_MultiplierAP || ', CM=' || v_MultiplierCM); + + -- Calculate Allocated Amount + FOR a IN Cur_Alloc LOOP + v_Temp := a.Amount + a.DisCountAmt + a.WriteOffAmt; + v_PaidAmt := v_PaidAmt + -- Allocation + + currencyConvert(v_Temp * v_MultiplierAP, + a.C_Currency_ID, v_Currency_ID, a.DateTrx, null, a.AD_Client_ID, a.AD_Org_ID); + DBMS_OUTPUT.PUT_LINE(' PaidAmt=' || v_PaidAmt || ', Allocation=' || v_Temp || ' * ' || v_MultiplierAP); + END LOOP; + + -- Do we have a Payment Schedule ? + IF (p_C_InvoicePaySchedule_ID > 0) THEN -- if not valid = lists invoice amount + v_Remaining := v_PaidAmt; + FOR s IN Cur_PaySchedule LOOP + IF (s.C_InvoicePaySchedule_ID = p_C_InvoicePaySchedule_ID) THEN + v_TotalOpenAmt := (s.DueAmt*v_MultiplierCM) - v_Remaining; + IF (s.DueAmt - v_Remaining < 0) THEN + v_TotalOpenAmt := 0; + END IF; + -- DBMS_OUTPUT.PUT_LINE('Sched Total=' || v_TotalOpenAmt || ', Due=' || s.DueAmt || ',Remaining=' || v_Remaining || ',CM=' || v_MultiplierCM); + ELSE -- calculate amount, which can be allocated to next schedule + v_Remaining := v_Remaining - s.DueAmt; + IF (v_Remaining < 0) THEN + v_Remaining := 0; + END IF; + -- DBMS_OUTPUT.PUT_LINE('Remaining=' || v_Remaining); + END IF; + END LOOP; + ELSE + v_TotalOpenAmt := v_TotalOpenAmt - v_PaidAmt; + END IF; +-- DBMS_OUTPUT.PUT_LINE('== Total=' || v_TotalOpenAmt); + + -- Ignore Rounding + IF (v_TotalOpenAmt BETWEEN -0.00999 AND 0.00999) THEN + v_TotalOpenAmt := 0; + END IF; + + -- Round to penny + v_TotalOpenAmt := ROUND(COALESCE(v_TotalOpenAmt,0), 2); + RETURN v_TotalOpenAmt; +END invoiceOpen; +/