IDEMPIERE-1856 Amount in database functions and views are hardcoded to round to 2 decimal points
This commit is contained in:
parent
1abe2ca2ba
commit
d4c674ce72
|
@ -133,3 +133,104 @@ BEGIN
|
|||
END;
|
||||
$BODY$
|
||||
LANGUAGE 'plpgsql' ;
|
||||
|
||||
CREATE OR REPLACE FUNCTION InvoiceopenToDate
|
||||
(
|
||||
p_C_Invoice_ID IN numeric,
|
||||
p_C_InvoicePaySchedule_ID IN numeric,
|
||||
p_DateAcct IN date
|
||||
)
|
||||
RETURNS numeric
|
||||
AS
|
||||
$BODY$
|
||||
DECLARE
|
||||
v_Currency_ID numeric(10);
|
||||
v_Precision NUMERIC := 0;
|
||||
v_Min NUMERIC := 0;
|
||||
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);
|
||||
|
||||
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 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 > -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' ;
|
|
@ -137,6 +137,107 @@ END;
|
|||
$BODY$
|
||||
LANGUAGE 'plpgsql' ;
|
||||
|
||||
CREATE OR REPLACE FUNCTION InvoiceopenToDate
|
||||
(
|
||||
p_C_Invoice_ID IN numeric,
|
||||
p_C_InvoicePaySchedule_ID IN numeric,
|
||||
p_DateAcct IN date
|
||||
)
|
||||
RETURNS numeric
|
||||
AS
|
||||
$BODY$
|
||||
DECLARE
|
||||
v_Currency_ID numeric(10);
|
||||
v_Precision NUMERIC := 0;
|
||||
v_Min NUMERIC := 0;
|
||||
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);
|
||||
|
||||
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 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 > -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' ;
|
||||
|
||||
CREATE OR REPLACE FUNCTION invoicePaid
|
||||
(
|
||||
p_C_Invoice_ID NUMERIC,
|
||||
|
|
Loading…
Reference in New Issue