BF [ 2714803 ]

- Fixed wrong select sql use in the for loop
BF [ 2714831 ]
- p_DateAcct parameter have wrong datatype, should be "timestamp with time zone" instead of "date"
This commit is contained in:
Heng Sin Low 2009-03-27 05:55:58 +00:00
parent 66665f2594
commit 9d1cfc5ca6
4 changed files with 199 additions and 0 deletions

View File

@ -0,0 +1 @@
-- postgresql only

View File

@ -0,0 +1,2 @@
-- postgresql only

View File

@ -0,0 +1,71 @@
/*
*This file is part of Adempiere ERP Bazaar
*http://www.adempiere.org
*Copyright (C) 2006-2008 victor.perez@e-evolution.com, e-Evolution
*This program is free software; you can redistribute it and/or
*modify it under the terms of the GNU General Public License
*as published by the Free Software Foundation; either version 2
*of the License, or (at your option) any later version.
*
*This program is distributed in the hope that it will be useful,
*but WITHOUT ANY WARRANTY; without even the implied warranty of
*MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the
*GNU General Public License for more details.
*
*You should have received a copy of the GNU General Public License
*along with this program; if not, write to the Free Software
*Foundation, Inc., 51 Franklin Street, Fifth Floor, Boston, MA 02110-1301, USA.of
* Title: Calculate Paid/Allocated amount in Currency
* Description:
* Add up total amount paid for for C_Invoice_ID.
* Split Payments are ignored.
* all allocation amounts converted to invoice C_Currency_ID
* round it to the nearest cent
* and adjust for CreditMemos by using C_Invoice_v
* and for Payments with the multiplierAP (-1, 1)
*
SELECT C_Invoice_ID, IsPaid, IsSOTrx, GrandTotal,
C_Invoice_Paid (C_Invoice_ID, C_Currency_ID, MultiplierAP, DateAcct)
FROM C_Invoice_v;
--
UPDATE C_Invoice_v1
SET IsPaid = CASE WHEN C_Invoice_Paid(C_Invoice_ID,C_Currency_ID,MultiplierAP,DateAcct)=GrandTotal THEN 'Y' ELSE 'N' END
WHERE C_Invoice_ID>1000000
*
************************************************************************/
CREATE OR REPLACE FUNCTION InvoicepaidToDate
(
p_C_Invoice_ID IN numeric,
p_C_Currency_ID IN numeric,
p_MultiplierAP IN numeric, -- DEFAULT 1
p_DateAcct IN timestamp with time zone
)
RETURNS numeric
AS
$BODY$
DECLARE
v_MultiplierAP numeric := 1;
v_PaymentAmt numeric := 0;
allocation record;
BEGIN
-- Default
IF (p_MultiplierAP IS NOT NULL) THEN
v_MultiplierAP := p_MultiplierAP;
END IF;
-- Calculate Allocated Amount
FOR allocation IN
SELECT al.AD_Client_ID, al.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' AND a.DateAcct <= p_DateAcct
LOOP
v_PaymentAmt := v_PaymentAmt
+ Currencyconvert(allocation.Amount + allocation.DisCountAmt + allocation.WriteOffAmt,
allocation.C_Currency_ID, p_C_Currency_ID, allocation.DateTrx, NULL, allocation.AD_Client_ID, allocation.AD_Org_ID);
END LOOP;
--
RETURN ROUND(COALESCE(v_PaymentAmt,0), 2) * v_MultiplierAP;
END;
$BODY$
LANGUAGE 'plpgsql' ;

View File

@ -0,0 +1,125 @@
/*
*This file is part of Adempiere ERP Bazaar
*http://www.adempiere.org
*Copyright (C) 2006-2008 victor.perez@e-evolution.com, e-Evolution
*This program is free software; you can redistribute it and/or
*modify it under the terms of the GNU General Public License
*as published by the Free Software Foundation; either version 2
*of the License, or (at your option) any later version.
*
*This program is distributed in the hope that it will be useful,
*but WITHOUT ANY WARRANTY; without even the implied warranty of
*MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the
*GNU General Public License for more details.
*
*You should have received a copy of the GNU General Public License
*along with this program; if not, write to the Free Software
*Foundation, Inc., 51 Franklin Street, Fifth Floor, Boston, MA 02110-1301, USA.of
* 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
************************************************************************/
CREATE OR REPLACE FUNCTION InvoiceopenToDate
(
p_C_Invoice_ID IN numeric,
p_C_InvoicePaySchedule_ID IN numeric,
p_DateAcct IN timestamp with time zone
)
RETURNS numeric
AS
$BODY$
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;
allocationline record;
invoiceschedule 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
AND DateAcct <= p_DateAcct;
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 allocationline 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.DateAcct <= p_DateAcct
AND a.IsActive='Y'
LOOP
v_Temp := allocationline.Amount + allocationline.DisCountAmt + allocationline.WriteOffAmt;
v_PaidAmt := v_PaidAmt
-- Allocation
+ Currencyconvert(v_Temp * v_MultiplierAP,
allocationline.C_Currency_ID, v_Currency_ID, allocationline.DateTrx, NULL, allocationline.AD_Client_ID, allocationline.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 invoiceschedule 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 (invoiceschedule.C_InvoicePaySchedule_ID = p_C_InvoicePaySchedule_ID) THEN
v_TotalOpenAmt := (invoiceschedule.DueAmt*v_MultiplierCM) - v_Remaining;
IF (invoiceschedule.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 - invoiceschedule.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;
$BODY$
LANGUAGE 'plpgsql' ;