BF [2804321] - Invoice Open function doesn't respect currency precision

https://sourceforge.net/tracker/?func=detail&aid=2804321&group_id=176962&atid=879332
This commit is contained in:
Carlos Ruiz 2009-06-10 18:24:58 +00:00
parent e3d910e4a0
commit a255992858
3 changed files with 139 additions and 17 deletions

View File

@ -1,9 +1,5 @@
CREATE OR REPLACE FUNCTION invoiceOpen
(
p_C_Invoice_ID IN NUMERIC,
p_C_InvoicePaySchedule_ID IN NUMERIC
)
RETURNS numeric AS $body$
CREATE OR REPLACE FUNCTION invoiceopen (in p_c_invoice_id numeric, in 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
@ -39,6 +35,8 @@ DECLARE
v_MultiplierAP NUMERIC := 0;
v_MultiplierCM NUMERIC := 0;
v_Temp NUMERIC := 0;
v_Precision NUMERIC := 0;
v_Min NUMERIC := 0;
ar RECORD;
s RECORD;
@ -55,6 +53,13 @@ BEGIN
RETURN NULL;
END;
SELECT StdPrecision
INTO v_Precision
FROM C_Currency
WHERE C_Currency_ID = v_Currency_ID;
SELECT 1/10^v_Precision INTO v_Min;
-- Calculate Allocated Amount
FOR ar IN
SELECT a.AD_Client_ID, a.AD_Org_ID,
@ -98,22 +103,18 @@ BEGIN
ELSE
v_TotalOpenAmt := v_TotalOpenAmt - v_PaidAmt;
END IF;
-- RAISE NOTICE '== Total=' || v_TotalOpenAmt;
-- RAISE NOTICE ''== Total='' || v_TotalOpenAmt;
-- Ignore Rounding
IF (v_TotalOpenAmt BETWEEN -0.00999 AND 0.00999) THEN
IF (v_TotalOpenAmt > -v_Min AND v_TotalOpenAmt < v_Min) THEN
v_TotalOpenAmt := 0;
END IF;
-- Round to penny
v_TotalOpenAmt := ROUND(COALESCE(v_TotalOpenAmt,0), 2);
-- Round to currency precision
v_TotalOpenAmt := ROUND(COALESCE(v_TotalOpenAmt,0), v_Precision);
RETURN v_TotalOpenAmt;
END;
$body$ LANGUAGE plpgsql;
$BODY$
LANGUAGE 'plpgsql'
;

View File

@ -0,0 +1 @@
-- Just for postgresql

View File

@ -0,0 +1,120 @@
CREATE OR REPLACE FUNCTION invoiceopen (in p_c_invoice_id numeric, in 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 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.
* Cannot be used for IsPaid as mutating
*
* Test:
* SELECT C_InvoicePaySchedule_ID, DueAmt FROM C_InvoicePaySchedule WHERE C_Invoice_ID=109 ORDER BY DueDate;
* SELECT invoiceOpen (109, null) FROM AD_System; - converted to default client currency
* SELECT invoiceOpen (109, 11) FROM AD_System; - converted to default client currency
* SELECT invoiceOpen (109, 102) FROM AD_System;
* SELECT invoiceOpen (109, 103) FROM AD_System;
************************************************************************/
DECLARE
v_Currency_ID NUMERIC(10);
v_TotalOpenAmt NUMERIC := 0;
v_PaidAmt NUMERIC := 0;
v_Remaining NUMERIC := 0;
v_MultiplierAP NUMERIC := 0;
v_MultiplierCM NUMERIC := 0;
v_Temp NUMERIC := 0;
v_Precision NUMERIC := 0;
v_Min NUMERIC := 0;
ar RECORD;
s RECORD;
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
RAISE NOTICE 'InvoiceOpen - %', SQLERRM;
RETURN NULL;
END;
SELECT StdPrecision
INTO v_Precision
FROM C_Currency
WHERE C_Currency_ID = v_Currency_ID;
SELECT 1/10^v_Precision INTO v_Min;
-- Calculate Allocated Amount
FOR ar IN
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'
LOOP
v_Temp := ar.Amount + ar.DisCountAmt + ar.WriteOffAmt;
v_PaidAmt := v_PaidAmt
-- Allocation
+ currencyConvert(v_Temp * v_MultiplierAP,
ar.C_Currency_ID, v_Currency_ID, ar.DateTrx, null, ar.AD_Client_ID, ar.AD_Org_ID);
RAISE NOTICE ' PaidAmt=% , Allocation= % * %', v_PaidAmt, 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
SELECT C_InvoicePaySchedule_ID, DueAmt
FROM C_InvoicePaySchedule
WHERE C_Invoice_ID = p_C_Invoice_ID
AND IsValid='Y'
ORDER BY DueDate
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;
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;
END IF;
END LOOP;
ELSE
v_TotalOpenAmt := v_TotalOpenAmt - v_PaidAmt;
END IF;
-- RAISE NOTICE ''== Total='' || v_TotalOpenAmt;
-- Ignore Rounding
IF (v_TotalOpenAmt > -v_Min AND v_TotalOpenAmt < v_Min) THEN
v_TotalOpenAmt := 0;
END IF;
-- Round to currency precision
v_TotalOpenAmt := ROUND(COALESCE(v_TotalOpenAmt,0), v_Precision);
RETURN v_TotalOpenAmt;
END;
$BODY$
LANGUAGE 'plpgsql'
;