IDEMPIERE-1856 Amount in database functions and views are hardcoded to round to 2 decimal points
This commit is contained in:
parent
036f065d70
commit
1abe2ca2ba
|
@ -33,6 +33,8 @@ SELECT C_InvoicePaySchedule_ID, DueAmt FROM C_InvoicePaySchedule WHERE C_Invoice
|
||||||
************************************************************************/
|
************************************************************************/
|
||||||
AS
|
AS
|
||||||
v_Currency_ID NUMBER(10);
|
v_Currency_ID NUMBER(10);
|
||||||
|
v_Precision NUMBER := 0;
|
||||||
|
v_Min NUMBER := 0;
|
||||||
v_TotalOpenAmt NUMBER := 0;
|
v_TotalOpenAmt NUMBER := 0;
|
||||||
v_PaidAmt NUMBER := 0;
|
v_PaidAmt NUMBER := 0;
|
||||||
v_Remaining NUMBER := 0;
|
v_Remaining NUMBER := 0;
|
||||||
|
@ -70,6 +72,13 @@ BEGIN
|
||||||
END;
|
END;
|
||||||
-- DBMS_OUTPUT.PUT_LINE('== C_Invoice_ID=' || p_C_Invoice_ID || ', Total=' || v_TotalOpenAmt || ', AP=' || v_MultiplierAP || ', CM=' || v_MultiplierCM);
|
-- 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 POWER(1/10,v_Precision) INTO v_Min FROM DUAL;
|
||||||
|
|
||||||
-- Calculate Allocated Amount
|
-- Calculate Allocated Amount
|
||||||
FOR a IN Cur_Alloc LOOP
|
FOR a IN Cur_Alloc LOOP
|
||||||
v_Temp := a.Amount + a.DisCountAmt + a.WriteOffAmt;
|
v_Temp := a.Amount + a.DisCountAmt + a.WriteOffAmt;
|
||||||
|
@ -104,12 +113,13 @@ BEGIN
|
||||||
-- DBMS_OUTPUT.PUT_LINE('== Total=' || v_TotalOpenAmt);
|
-- DBMS_OUTPUT.PUT_LINE('== Total=' || v_TotalOpenAmt);
|
||||||
|
|
||||||
-- Ignore Rounding
|
-- 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;
|
v_TotalOpenAmt := 0;
|
||||||
END IF;
|
END IF;
|
||||||
|
|
||||||
-- Round to penny
|
-- Round to currency precision
|
||||||
v_TotalOpenAmt := ROUND(COALESCE(v_TotalOpenAmt,0), 2);
|
v_TotalOpenAmt := ROUND(COALESCE(v_TotalOpenAmt,0), v_Precision);
|
||||||
RETURN v_TotalOpenAmt;
|
|
||||||
|
RETURN v_TotalOpenAmt;
|
||||||
END invoiceOpen;
|
END invoiceOpen;
|
||||||
/
|
/
|
||||||
|
|
|
@ -34,6 +34,8 @@ SELECT C_InvoicePaySchedule_ID, DueAmt FROM C_InvoicePaySchedule WHERE C_Invoice
|
||||||
************************************************************************/
|
************************************************************************/
|
||||||
AS
|
AS
|
||||||
v_Currency_ID NUMBER(10);
|
v_Currency_ID NUMBER(10);
|
||||||
|
v_Precision NUMBER := 0;
|
||||||
|
v_Min NUMBER := 0;
|
||||||
v_TotalOpenAmt NUMBER := 0;
|
v_TotalOpenAmt NUMBER := 0;
|
||||||
v_PaidAmt NUMBER := 0;
|
v_PaidAmt NUMBER := 0;
|
||||||
v_Remaining NUMBER := 0;
|
v_Remaining NUMBER := 0;
|
||||||
|
@ -73,6 +75,13 @@ BEGIN
|
||||||
END;
|
END;
|
||||||
-- DBMS_OUTPUT.PUT_LINE('== C_Invoice_ID=' || p_C_Invoice_ID || ', Total=' || v_TotalOpenAmt || ', AP=' || v_MultiplierAP || ', CM=' || v_MultiplierCM);
|
-- 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 POWER(1/10,v_Precision) INTO v_Min FROM DUAL;
|
||||||
|
|
||||||
-- Calculate Allocated Amount
|
-- Calculate Allocated Amount
|
||||||
FOR a IN Cur_Alloc LOOP
|
FOR a IN Cur_Alloc LOOP
|
||||||
v_Temp := a.Amount + a.DisCountAmt + a.WriteOffAmt;
|
v_Temp := a.Amount + a.DisCountAmt + a.WriteOffAmt;
|
||||||
|
@ -106,13 +115,14 @@ BEGIN
|
||||||
END IF;
|
END IF;
|
||||||
-- DBMS_OUTPUT.PUT_LINE('== Total=' || v_TotalOpenAmt);
|
-- DBMS_OUTPUT.PUT_LINE('== Total=' || v_TotalOpenAmt);
|
||||||
|
|
||||||
-- Ignore Rounding
|
-- 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;
|
v_TotalOpenAmt := 0;
|
||||||
END IF;
|
END IF;
|
||||||
|
|
||||||
-- Round to penny
|
-- Round to currency precision
|
||||||
v_TotalOpenAmt := ROUND(COALESCE(v_TotalOpenAmt,0), 2);
|
v_TotalOpenAmt := ROUND(COALESCE(v_TotalOpenAmt,0), v_Precision);
|
||||||
RETURN v_TotalOpenAmt;
|
|
||||||
|
RETURN v_TotalOpenAmt;
|
||||||
END InvoiceopenToDate;
|
END InvoiceopenToDate;
|
||||||
/
|
/
|
||||||
|
|
|
@ -33,6 +33,8 @@ RETURN NUMBER
|
||||||
*
|
*
|
||||||
************************************************************************/
|
************************************************************************/
|
||||||
AS
|
AS
|
||||||
|
v_Precision NUMBER := 0;
|
||||||
|
v_Min NUMBER := 0;
|
||||||
v_MultiplierAP NUMBER := 1;
|
v_MultiplierAP NUMBER := 1;
|
||||||
v_PaymentAmt NUMBER := 0;
|
v_PaymentAmt NUMBER := 0;
|
||||||
CURSOR Cur_Alloc IS
|
CURSOR Cur_Alloc IS
|
||||||
|
@ -44,6 +46,13 @@ AS
|
||||||
WHERE al.C_Invoice_ID = p_C_Invoice_ID
|
WHERE al.C_Invoice_ID = p_C_Invoice_ID
|
||||||
AND a.IsActive='Y';
|
AND a.IsActive='Y';
|
||||||
BEGIN
|
BEGIN
|
||||||
|
SELECT StdPrecision
|
||||||
|
INTO v_Precision
|
||||||
|
FROM C_Currency
|
||||||
|
WHERE C_Currency_ID = p_C_Currency_ID;
|
||||||
|
|
||||||
|
SELECT POWER(1/10,v_Precision) INTO v_Min FROM DUAL;
|
||||||
|
|
||||||
-- Default
|
-- Default
|
||||||
IF (p_MultiplierAP IS NOT NULL) THEN
|
IF (p_MultiplierAP IS NOT NULL) THEN
|
||||||
v_MultiplierAP := p_MultiplierAP;
|
v_MultiplierAP := p_MultiplierAP;
|
||||||
|
@ -54,7 +63,15 @@ BEGIN
|
||||||
+ currencyConvert(a.Amount + a.DisCountAmt + a.WriteOffAmt,
|
+ currencyConvert(a.Amount + a.DisCountAmt + a.WriteOffAmt,
|
||||||
a.C_Currency_ID, p_C_Currency_ID, a.DateTrx, null, a.AD_Client_ID, a.AD_Org_ID);
|
a.C_Currency_ID, p_C_Currency_ID, a.DateTrx, null, a.AD_Client_ID, a.AD_Org_ID);
|
||||||
END LOOP;
|
END LOOP;
|
||||||
--
|
|
||||||
RETURN ROUND(NVL(v_PaymentAmt,0), 2) * v_MultiplierAP;
|
-- Ignore Rounding
|
||||||
|
IF (v_PaymentAmt > -v_Min AND v_PaymentAmt < v_Min) THEN
|
||||||
|
v_PaymentAmt := 0;
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
-- Round to currency precision
|
||||||
|
v_PaymentAmt := ROUND(COALESCE(v_PaymentAmt,0), v_Precision);
|
||||||
|
|
||||||
|
RETURN v_PaymentAmt * v_MultiplierAP;
|
||||||
END invoicePaid;
|
END invoicePaid;
|
||||||
/
|
/
|
|
@ -34,6 +34,8 @@ RETURN NUMBER
|
||||||
*
|
*
|
||||||
************************************************************************/
|
************************************************************************/
|
||||||
AS
|
AS
|
||||||
|
v_Precision NUMBER := 0;
|
||||||
|
v_Min NUMBER := 0;
|
||||||
v_MultiplierAP NUMBER := 1;
|
v_MultiplierAP NUMBER := 1;
|
||||||
v_PaymentAmt NUMBER := 0;
|
v_PaymentAmt NUMBER := 0;
|
||||||
CURSOR Cur_Alloc IS
|
CURSOR Cur_Alloc IS
|
||||||
|
@ -46,6 +48,13 @@ AS
|
||||||
AND a.IsActive='Y'
|
AND a.IsActive='Y'
|
||||||
AND a.DateAcct <= p_DateAcct;
|
AND a.DateAcct <= p_DateAcct;
|
||||||
BEGIN
|
BEGIN
|
||||||
|
SELECT StdPrecision
|
||||||
|
INTO v_Precision
|
||||||
|
FROM C_Currency
|
||||||
|
WHERE C_Currency_ID = p_C_Currency_ID;
|
||||||
|
|
||||||
|
SELECT POWER(1/10,v_Precision) INTO v_Min FROM DUAL;
|
||||||
|
|
||||||
-- Default
|
-- Default
|
||||||
IF (p_MultiplierAP IS NOT NULL) THEN
|
IF (p_MultiplierAP IS NOT NULL) THEN
|
||||||
v_MultiplierAP := p_MultiplierAP;
|
v_MultiplierAP := p_MultiplierAP;
|
||||||
|
@ -56,7 +65,15 @@ BEGIN
|
||||||
+ Currencyconvert(a.Amount + a.DisCountAmt + a.WriteOffAmt,
|
+ Currencyconvert(a.Amount + a.DisCountAmt + a.WriteOffAmt,
|
||||||
a.C_Currency_ID, p_C_Currency_ID, a.DateTrx, NULL, a.AD_Client_ID, a.AD_Org_ID);
|
a.C_Currency_ID, p_C_Currency_ID, a.DateTrx, NULL, a.AD_Client_ID, a.AD_Org_ID);
|
||||||
END LOOP;
|
END LOOP;
|
||||||
--
|
|
||||||
RETURN ROUND(NVL(v_PaymentAmt,0), 2) * v_MultiplierAP;
|
-- Ignore Rounding
|
||||||
|
IF (v_PaymentAmt > -v_Min AND v_PaymentAmt < v_Min) THEN
|
||||||
|
v_PaymentAmt := 0;
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
-- Round to currency precision
|
||||||
|
v_PaymentAmt := ROUND(COALESCE(v_PaymentAmt,0), v_Precision);
|
||||||
|
|
||||||
|
RETURN v_PaymentAmt * v_MultiplierAP;
|
||||||
END InvoicepaidToDate;
|
END InvoicepaidToDate;
|
||||||
/
|
/
|
||||||
|
|
|
@ -24,6 +24,8 @@ RETURN NUMBER
|
||||||
************************************************************************/
|
************************************************************************/
|
||||||
|
|
||||||
AS
|
AS
|
||||||
|
v_Precision NUMBER := 0;
|
||||||
|
v_Min NUMBER := 0;
|
||||||
Discount NUMBER := 0;
|
Discount NUMBER := 0;
|
||||||
CURSOR Cur_PT IS
|
CURSOR Cur_PT IS
|
||||||
SELECT *
|
SELECT *
|
||||||
|
@ -34,6 +36,13 @@ AS
|
||||||
Add1Date NUMBER := 0;
|
Add1Date NUMBER := 0;
|
||||||
Add2Date NUMBER := 0;
|
Add2Date NUMBER := 0;
|
||||||
BEGIN
|
BEGIN
|
||||||
|
SELECT StdPrecision
|
||||||
|
INTO v_Precision
|
||||||
|
FROM C_Currency
|
||||||
|
WHERE C_Currency_ID = Currency_ID;
|
||||||
|
|
||||||
|
SELECT POWER(1/10,v_Precision) INTO v_Min FROM DUAL;
|
||||||
|
|
||||||
-- No Data - No Discount
|
-- No Data - No Discount
|
||||||
IF (Amount IS NULL OR PaymentTerm_ID IS NULL OR DocDate IS NULL) THEN
|
IF (Amount IS NULL OR PaymentTerm_ID IS NULL OR DocDate IS NULL) THEN
|
||||||
RETURN 0;
|
RETURN 0;
|
||||||
|
@ -60,7 +69,15 @@ BEGIN
|
||||||
Discount := Amount * p.Discount2 / 100;
|
Discount := Amount * p.Discount2 / 100;
|
||||||
END IF;
|
END IF;
|
||||||
END LOOP;
|
END LOOP;
|
||||||
--
|
|
||||||
RETURN ROUND(NVL(Discount,0), 2); -- fixed rounding
|
-- Ignore Rounding
|
||||||
|
IF (Discount > -v_Min AND Discount < v_Min) THEN
|
||||||
|
Discount := 0;
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
-- Round to currency precision
|
||||||
|
Discount := ROUND(COALESCE(Discount,0), v_Precision);
|
||||||
|
|
||||||
|
RETURN Discount;
|
||||||
END paymentTermDiscount;
|
END paymentTermDiscount;
|
||||||
/
|
/
|
|
@ -26,6 +26,8 @@ RETURN NUMBER
|
||||||
|
|
||||||
************************************************************************/
|
************************************************************************/
|
||||||
AS
|
AS
|
||||||
|
v_Precision NUMBER := 0;
|
||||||
|
v_Min NUMBER := 0;
|
||||||
v_AllocatedAmt NUMBER := 0;
|
v_AllocatedAmt NUMBER := 0;
|
||||||
v_PayAmt NUMBER;
|
v_PayAmt NUMBER;
|
||||||
CURSOR Cur_Alloc IS
|
CURSOR Cur_Alloc IS
|
||||||
|
@ -36,6 +38,13 @@ AS
|
||||||
AND a.IsActive='Y';
|
AND a.IsActive='Y';
|
||||||
-- AND al.C_Invoice_ID IS NOT NULL;
|
-- AND al.C_Invoice_ID IS NOT NULL;
|
||||||
BEGIN
|
BEGIN
|
||||||
|
SELECT StdPrecision
|
||||||
|
INTO v_Precision
|
||||||
|
FROM C_Currency
|
||||||
|
WHERE C_Currency_ID = p_C_Currency_ID;
|
||||||
|
|
||||||
|
SELECT POWER(1/10,v_Precision) INTO v_Min FROM DUAL;
|
||||||
|
|
||||||
-- Charge - nothing available
|
-- Charge - nothing available
|
||||||
SELECT MAX(PayAmt)
|
SELECT MAX(PayAmt)
|
||||||
INTO v_PayAmt
|
INTO v_PayAmt
|
||||||
|
@ -50,8 +59,15 @@ BEGIN
|
||||||
v_AllocatedAmt := v_AllocatedAmt
|
v_AllocatedAmt := v_AllocatedAmt
|
||||||
+ currencyConvert(a.Amount, a.C_Currency_ID, p_C_Currency_ID, a.DateTrx, null, a.AD_Client_ID, a.AD_Org_ID);
|
+ currencyConvert(a.Amount, a.C_Currency_ID, p_C_Currency_ID, a.DateTrx, null, a.AD_Client_ID, a.AD_Org_ID);
|
||||||
END LOOP;
|
END LOOP;
|
||||||
-- Round to penny
|
|
||||||
v_AllocatedAmt := ROUND(NVL(v_AllocatedAmt,0), 2);
|
-- Ignore Rounding
|
||||||
|
IF (v_AllocatedAmt > -v_Min AND v_AllocatedAmt < v_Min) THEN
|
||||||
|
v_AllocatedAmt := 0;
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
-- Round to currency precision
|
||||||
|
v_AllocatedAmt := ROUND(COALESCE(v_AllocatedAmt,0), v_Precision);
|
||||||
|
|
||||||
RETURN v_AllocatedAmt;
|
RETURN v_AllocatedAmt;
|
||||||
END paymentAllocated;
|
END paymentAllocated;
|
||||||
/
|
/
|
|
@ -18,6 +18,8 @@ RETURN NUMBER
|
||||||
************************************************************************/
|
************************************************************************/
|
||||||
AS
|
AS
|
||||||
v_Currency_ID NUMBER(10);
|
v_Currency_ID NUMBER(10);
|
||||||
|
v_Precision NUMBER := 0;
|
||||||
|
v_Min NUMBER := 0;
|
||||||
v_AvailableAmt NUMBER := 0;
|
v_AvailableAmt NUMBER := 0;
|
||||||
v_IsReceipt C_Payment.IsReceipt%TYPE;
|
v_IsReceipt C_Payment.IsReceipt%TYPE;
|
||||||
v_Amt NUMBER := 0;
|
v_Amt NUMBER := 0;
|
||||||
|
@ -45,18 +47,28 @@ BEGIN
|
||||||
WHERE C_Payment_ID = p_C_Payment_ID;
|
WHERE C_Payment_ID = p_C_Payment_ID;
|
||||||
-- DBMS_OUTPUT.PUT_LINE('== C_Payment_ID=' || p_C_Payment_ID || ', PayAmt=' || v_AvailableAmt || ', Receipt=' || v_IsReceipt);
|
-- DBMS_OUTPUT.PUT_LINE('== C_Payment_ID=' || p_C_Payment_ID || ', PayAmt=' || v_AvailableAmt || ', Receipt=' || v_IsReceipt);
|
||||||
|
|
||||||
|
SELECT StdPrecision
|
||||||
|
INTO v_Precision
|
||||||
|
FROM C_Currency
|
||||||
|
WHERE C_Currency_ID = v_Currency_ID;
|
||||||
|
|
||||||
|
SELECT POWER(1/10,v_Precision) INTO v_Min FROM DUAL;
|
||||||
|
|
||||||
-- Calculate Allocated Amount
|
-- Calculate Allocated Amount
|
||||||
FOR a IN Cur_Alloc LOOP
|
FOR a IN Cur_Alloc LOOP
|
||||||
v_Amt := currencyConvert(a.Amount, a.C_Currency_ID, v_Currency_ID, a.DateTrx, null, a.AD_Client_ID, a.AD_Org_ID);
|
v_Amt := currencyConvert(a.Amount, a.C_Currency_ID, v_Currency_ID, a.DateTrx, null, a.AD_Client_ID, a.AD_Org_ID);
|
||||||
v_AvailableAmt := v_AvailableAmt - v_Amt;
|
v_AvailableAmt := v_AvailableAmt - v_Amt;
|
||||||
-- DBMS_OUTPUT.PUT_LINE(' Allocation=' || a.Amount || ' - Available=' || v_AvailableAmt);
|
-- DBMS_OUTPUT.PUT_LINE(' Allocation=' || a.Amount || ' - Available=' || v_AvailableAmt);
|
||||||
END LOOP;
|
END LOOP;
|
||||||
|
|
||||||
-- Ignore Rounding
|
-- Ignore Rounding
|
||||||
IF (v_AvailableAmt BETWEEN -0.00999 AND 0.00999) THEN
|
IF (v_AvailableAmt > -v_Min AND v_AvailableAmt < v_Min) THEN
|
||||||
v_AvailableAmt := 0;
|
v_AvailableAmt := 0;
|
||||||
END IF;
|
END IF;
|
||||||
-- Round to penny
|
|
||||||
v_AvailableAmt := ROUND(NVL(v_AvailableAmt,0), 2);
|
-- Round to currency precision
|
||||||
|
v_AvailableAmt := ROUND(COALESCE(v_AvailableAmt,0), v_Precision);
|
||||||
|
|
||||||
RETURN v_AvailableAmt;
|
RETURN v_AvailableAmt;
|
||||||
END paymentAvailable;
|
END paymentAvailable;
|
||||||
/
|
/
|
||||||
|
|
|
@ -11,11 +11,11 @@ SELECT il.AD_Client_ID, il.AD_Org_ID,
|
||||||
i.C_BPartner_ID, il.M_Product_ID,
|
i.C_BPartner_ID, il.M_Product_ID,
|
||||||
i.DocumentNo, i.DateInvoiced, i.DateAcct,
|
i.DocumentNo, i.DateInvoiced, i.DateAcct,
|
||||||
i.IsSOTrx, i.DocStatus,
|
i.IsSOTrx, i.DocStatus,
|
||||||
ROUND(i.Multiplier*LineNetAmt, 2) AS LineNetAmt,
|
currencyRound(i.Multiplier*LineNetAmt,i.C_Currency_ID,'N') AS LineNetAmt,
|
||||||
ROUND(i.Multiplier*PriceList*QtyInvoiced, 2) AS LineListAmt,
|
currencyRound(i.Multiplier*PriceList*QtyInvoiced,i.C_Currency_ID,'N') AS LineListAmt,
|
||||||
CASE WHEN COALESCE(il.PriceLimit, 0)=0 THEN ROUND(i.Multiplier*LineNetAmt,2) ELSE ROUND(i.Multiplier*PriceLimit*QtyInvoiced,2) END AS LineLimitAmt,
|
CASE WHEN COALESCE(il.PriceLimit, 0)=0 THEN currencyRound(i.Multiplier*LineNetAmt,i.C_Currency_ID,'N') ELSE currencyRound(i.Multiplier*il.PriceLimit*il.QtyInvoiced,i.C_Currency_ID,'N') END AS LineLimitAmt,
|
||||||
ROUND(i.Multiplier*PriceList*QtyInvoiced-LineNetAmt,2) AS LineDiscountAmt,
|
currencyRound(i.Multiplier*il.PriceList*il.QtyInvoiced-il.LineNetAmt,i.C_Currency_ID,'N') AS LineDiscountAmt,
|
||||||
CASE WHEN COALESCE(il.PriceLimit,0)=0 THEN 0 ELSE ROUND(i.Multiplier*LineNetAmt-PriceLimit*QtyInvoiced,2) END AS LineOverLimitAmt,
|
CASE WHEN COALESCE(il.PriceLimit,0)=0 THEN 0 ELSE currencyRound(i.Multiplier*il.LineNetAmt-il.PriceLimit*il.QtyInvoiced,i.C_Currency_ID,'N') END AS LineOverLimitAmt,
|
||||||
il.QtyInvoiced, il.QtyEntered,
|
il.QtyInvoiced, il.QtyEntered,
|
||||||
il.Line, il.C_OrderLine_ID, il.C_UOM_ID,
|
il.Line, il.C_OrderLine_ID, il.C_UOM_ID,
|
||||||
il.C_Campaign_ID, il.C_Project_ID, il.C_Activity_ID, il.C_ProjectPhase_ID, il.C_ProjectTask_ID
|
il.C_Campaign_ID, il.C_Project_ID, il.C_Activity_ID, il.C_ProjectPhase_ID, il.C_ProjectTask_ID
|
||||||
|
|
|
@ -13,7 +13,7 @@ SELECT s.ad_client_id,
|
||||||
sum(ms.qtyonhand - ms.qtyreserved) AS qtyavailable,
|
sum(ms.qtyonhand - ms.qtyreserved) AS qtyavailable,
|
||||||
sum(ms.qtyonhand) AS qtyonhand,
|
sum(ms.qtyonhand) AS qtyonhand,
|
||||||
sum(ms.qtyreserved) AS qtyreserved,
|
sum(ms.qtyreserved) AS qtyreserved,
|
||||||
ROUND(MAX(mpr.pricestd),0) AS pricestd,
|
currencyRound(MAX(mpr.pricestd),mpl.C_Currency_ID,'N') AS pricestd,
|
||||||
mpr.m_pricelist_version_id,
|
mpr.m_pricelist_version_id,
|
||||||
mw.m_warehouse_id,
|
mw.m_warehouse_id,
|
||||||
org.name AS orgname
|
org.name AS orgname
|
||||||
|
@ -23,6 +23,8 @@ SELECT s.ad_client_id,
|
||||||
JOIN m_locator ml ON ms.m_locator_id = ml.m_locator_id
|
JOIN m_locator ml ON ms.m_locator_id = ml.m_locator_id
|
||||||
JOIN m_warehouse mw ON ml.m_warehouse_id = mw.m_warehouse_id
|
JOIN m_warehouse mw ON ml.m_warehouse_id = mw.m_warehouse_id
|
||||||
JOIN m_productprice mpr ON ms.m_product_id = mpr.m_product_id
|
JOIN m_productprice mpr ON ms.m_product_id = mpr.m_product_id
|
||||||
|
JOIN m_pricelist_version mplv ON mplv.m_pricelist_version_id = mpr.m_pricelist_version_id
|
||||||
|
JOIN m_pricelist mpl ON mplv.m_pricelist_id = mpl.m_pricelist_id
|
||||||
JOIN ad_org org ON org.ad_org_id = mw.ad_org_id
|
JOIN ad_org org ON org.ad_org_id = mw.ad_org_id
|
||||||
GROUP BY s.ad_client_id,
|
GROUP BY s.ad_client_id,
|
||||||
s.ad_org_id,
|
s.ad_org_id,
|
||||||
|
@ -36,7 +38,8 @@ SELECT s.ad_client_id,
|
||||||
mw.m_warehouse_id,
|
mw.m_warehouse_id,
|
||||||
mpr.m_pricelist_version_id,
|
mpr.m_pricelist_version_id,
|
||||||
org.name,
|
org.name,
|
||||||
mp.name
|
mp.name,
|
||||||
|
mpl.C_Currency_ID
|
||||||
UNION
|
UNION
|
||||||
SELECT r.ad_client_id,
|
SELECT r.ad_client_id,
|
||||||
r.ad_org_id,
|
r.ad_org_id,
|
||||||
|
@ -52,7 +55,7 @@ SELECT s.ad_client_id,
|
||||||
sum(ms.qtyonhand - ms.qtyreserved) AS qtyavailable,
|
sum(ms.qtyonhand - ms.qtyreserved) AS qtyavailable,
|
||||||
sum(ms.qtyonhand) AS qtyonhand,
|
sum(ms.qtyonhand) AS qtyonhand,
|
||||||
sum(ms.qtyreserved) AS qtyreserved,
|
sum(ms.qtyreserved) AS qtyreserved,
|
||||||
ROUND(MAX(mpr.pricestd),0) AS pricestd,
|
currencyRound(MAX(mpr.pricestd),mpl.C_Currency_ID,'N') AS pricestd,
|
||||||
mpr.m_pricelist_version_id,
|
mpr.m_pricelist_version_id,
|
||||||
mw.m_warehouse_id,
|
mw.m_warehouse_id,
|
||||||
org.name AS orgname
|
org.name AS orgname
|
||||||
|
@ -62,6 +65,8 @@ SELECT s.ad_client_id,
|
||||||
JOIN m_locator ml ON ms.m_locator_id = ml.m_locator_id
|
JOIN m_locator ml ON ms.m_locator_id = ml.m_locator_id
|
||||||
JOIN m_warehouse mw ON ml.m_warehouse_id = mw.m_warehouse_id
|
JOIN m_warehouse mw ON ml.m_warehouse_id = mw.m_warehouse_id
|
||||||
JOIN m_productprice mpr ON ms.m_product_id = mpr.m_product_id
|
JOIN m_productprice mpr ON ms.m_product_id = mpr.m_product_id
|
||||||
|
JOIN m_pricelist_version mplv ON mplv.m_pricelist_version_id = mpr.m_pricelist_version_id
|
||||||
|
JOIN m_pricelist mpl ON mplv.m_pricelist_id = mpl.m_pricelist_id
|
||||||
JOIN ad_org org ON org.ad_org_id = mw.ad_org_id
|
JOIN ad_org org ON org.ad_org_id = mw.ad_org_id
|
||||||
GROUP BY r.ad_client_id,
|
GROUP BY r.ad_client_id,
|
||||||
r.ad_org_id,
|
r.ad_org_id,
|
||||||
|
@ -75,4 +80,5 @@ SELECT s.ad_client_id,
|
||||||
mw.m_warehouse_id,
|
mw.m_warehouse_id,
|
||||||
mpr.m_pricelist_version_id,
|
mpr.m_pricelist_version_id,
|
||||||
org.name,
|
org.name,
|
||||||
mp.name;
|
mp.name,
|
||||||
|
mpl.C_Currency_ID;
|
|
@ -1,156 +1,141 @@
|
||||||
CREATE OR REPLACE VIEW rv_c_invoiceline
|
CREATE OR REPLACE VIEW rv_c_invoiceline AS
|
||||||
AS
|
SELECT il.ad_client_id,
|
||||||
SELECT il.ad_client_id,
|
il.ad_org_id,
|
||||||
il.ad_org_id,
|
il.isactive,
|
||||||
il.isactive,
|
il.created,
|
||||||
il.created,
|
il.createdby,
|
||||||
il.createdby,
|
il.updated,
|
||||||
il.updated,
|
il.updatedby,
|
||||||
il.updatedby,
|
il.c_invoiceline_id,
|
||||||
il.c_invoiceline_id,
|
i.c_invoice_id,
|
||||||
i.c_invoice_id,
|
i.salesrep_id,
|
||||||
i.salesrep_id,
|
i.c_bpartner_id,
|
||||||
i.c_bpartner_id,
|
i.c_bp_group_id,
|
||||||
i.c_bp_group_id,
|
il.m_product_id,
|
||||||
il.m_product_id,
|
p.m_product_category_id,
|
||||||
p.m_product_category_id,
|
i.dateinvoiced,
|
||||||
i.dateinvoiced,
|
i.dateacct,
|
||||||
i.dateacct,
|
i.issotrx,
|
||||||
i.issotrx,
|
i.c_doctype_id,
|
||||||
i.c_doctype_id,
|
i.docstatus,
|
||||||
i.docstatus,
|
i.ispaid,
|
||||||
i.ispaid,
|
il.c_campaign_id,
|
||||||
il.c_campaign_id,
|
il.c_project_id,
|
||||||
il.c_project_id,
|
il.c_activity_id,
|
||||||
il.c_activity_id,
|
il.c_projectphase_id,
|
||||||
il.c_projectphase_id,
|
il.c_projecttask_id,
|
||||||
il.c_projecttask_id,
|
il.qtyinvoiced * i.multiplier AS qtyinvoiced,
|
||||||
il.qtyinvoiced * i.multiplier AS qtyinvoiced,
|
il.qtyentered * i.multiplier AS qtyentered,
|
||||||
il.qtyentered * i.multiplier AS qtyentered,
|
il.m_attributesetinstance_id,
|
||||||
il.m_attributesetinstance_id,
|
productattribute(il.m_attributesetinstance_id) AS productattribute,
|
||||||
productattribute(il.m_attributesetinstance_id) AS productattribute,
|
pasi.m_attributeset_id,
|
||||||
pasi.m_attributeset_id,
|
pasi.m_lot_id,
|
||||||
pasi.m_lot_id,
|
pasi.guaranteedate,
|
||||||
pasi.guaranteedate,
|
pasi.lot,
|
||||||
pasi.lot,
|
pasi.serno,
|
||||||
pasi.serno,
|
il.pricelist,
|
||||||
il.pricelist,
|
il.priceactual,
|
||||||
il.priceactual,
|
il.pricelimit,
|
||||||
il.pricelimit,
|
il.priceentered,
|
||||||
il.priceentered,
|
CASE WHEN il.pricelist = 0 THEN 0 ELSE currencyRound((il.pricelist - il.priceactual) / il.pricelist * 100,i.C_Currency_ID,'N') END AS discount,
|
||||||
CASE
|
CASE WHEN il.pricelimit = 0 THEN 0 ELSE currencyRound((il.priceactual - il.pricelimit) / il.pricelimit * 100,i.C_Currency_ID,'N') END AS margin,
|
||||||
WHEN il.pricelist = 0 THEN 0
|
CASE WHEN il.pricelimit = 0 THEN 0 ELSE (il.priceactual - il.pricelimit) * il.qtyinvoiced END AS marginamt,
|
||||||
ELSE round(( il.pricelist - il.priceactual ) / il.pricelist * 100, 2)
|
currencyRound(i.multiplier * il.linenetamt,i.C_Currency_ID,'N') AS linenetamt,
|
||||||
END AS discount,
|
currencyRound(i.multiplier * il.pricelist * il.qtyinvoiced,i.C_Currency_ID,'N') AS linelistamt,
|
||||||
CASE
|
CASE WHEN COALESCE(il.pricelimit, 0) = 0 THEN currencyRound(i.multiplier * il.linenetamt,i.C_Currency_ID,'N') ELSE currencyRound(i.multiplier * il.pricelimit * il.qtyinvoiced,i.C_Currency_ID,'N') END
|
||||||
WHEN il.pricelimit = 0 THEN 0
|
AS linelimitamt,
|
||||||
ELSE round(( il.priceactual - il.pricelimit ) / il.pricelimit * 100, 2)
|
currencyRound(i.multiplier * il.pricelist * il.qtyinvoiced - il.linenetamt,i.C_Currency_ID,'N') AS linediscountamt,
|
||||||
END AS margin,
|
CASE WHEN COALESCE(il.pricelimit, 0) = 0 THEN 0 ELSE currencyRound(i.multiplier * il.linenetamt - il.pricelimit * il.qtyinvoiced,i.C_Currency_ID,'N') END AS
|
||||||
CASE
|
lineoverlimitamt,
|
||||||
WHEN il.pricelimit = 0 THEN 0
|
il.ad_orgtrx_id,
|
||||||
ELSE ( il.priceactual - il.pricelimit ) * il.qtyinvoiced
|
il.a_processed,
|
||||||
END AS marginamt,
|
il.c_charge_id,
|
||||||
round(i.multiplier * il.linenetamt, 2) AS linenetamt,
|
il.c_orderline_id,
|
||||||
round(i.multiplier * il.pricelist * il.qtyinvoiced, 2) AS linelistamt,
|
il.c_tax_id,
|
||||||
CASE
|
il.c_uom_id AS c_invoiceline_c_uom_id,
|
||||||
WHEN COALESCE(il.pricelimit, 0) = 0 THEN round(i.multiplier * il.linenetamt, 2)
|
il.description AS c_invoiceline_description,
|
||||||
ELSE round(i.multiplier * il.pricelimit * il.qtyinvoiced, 2)
|
il.isdescription,
|
||||||
END AS linelimitamt,
|
il.isprinted,
|
||||||
round(i.multiplier * il.pricelist * il.qtyinvoiced - il.linenetamt, 2) AS linediscountamt,
|
il.line,
|
||||||
CASE
|
il.linenetamt AS c_invoiceline_linenetamt,
|
||||||
WHEN COALESCE(il.pricelimit, 0) = 0 THEN 0
|
il.linetotalamt,
|
||||||
ELSE round(i.multiplier * il.linenetamt - il.pricelimit * il.qtyinvoiced, 2)
|
il.m_inoutline_id,
|
||||||
END AS lineoverlimitamt,
|
il.m_rmaline_id,
|
||||||
il.ad_orgtrx_id,
|
il.processed,
|
||||||
il.a_processed,
|
il.ref_invoiceline_id,
|
||||||
il.c_charge_id,
|
il.rramt,
|
||||||
il.c_orderline_id,
|
il.rrstartdate,
|
||||||
il.c_tax_id,
|
il.s_resourceassignment_id,
|
||||||
il.c_uom_id AS c_invoiceline_c_uom_id,
|
il.taxamt,
|
||||||
il.description AS c_invoiceline_description,
|
il.user1_id,
|
||||||
il.isdescription,
|
il.user2_id,
|
||||||
il.isprinted,
|
p.ad_org_id AS m_product_ad_org_id,
|
||||||
il.line,
|
p.classification,
|
||||||
il.linenetamt AS c_invoiceline_linenetamt,
|
p.copyfrom AS m_product_copyfrom,
|
||||||
il.linetotalamt,
|
p.created AS m_product_created,
|
||||||
il.m_inoutline_id,
|
p.createdby AS m_product_createdby,
|
||||||
il.m_rmaline_id,
|
p.c_revenuerecognition_id,
|
||||||
il.processed,
|
p.c_subscriptiontype_id,
|
||||||
il.ref_invoiceline_id,
|
p.c_taxcategory_id,
|
||||||
il.rramt,
|
p.c_uom_id AS m_productline_c_uom_id,
|
||||||
il.rrstartdate,
|
p.description AS m_product_description,
|
||||||
il.s_resourceassignment_id,
|
p.descriptionurl,
|
||||||
il.taxamt,
|
p.discontinued,
|
||||||
il.user1_id,
|
p.discontinuedat,
|
||||||
il.user2_id,
|
p.documentnote,
|
||||||
p.ad_org_id AS m_product_ad_org_id,
|
p.group1,
|
||||||
p.classification,
|
p.group2,
|
||||||
p.copyfrom AS m_product_copyfrom,
|
p.guaranteedays,
|
||||||
p.created AS m_product_created,
|
p.guaranteedaysmin,
|
||||||
p.createdby AS m_product_createdby,
|
p.help,
|
||||||
p.c_revenuerecognition_id,
|
p.imageurl,
|
||||||
p.c_subscriptiontype_id,
|
p.isactive AS m_product_isactive,
|
||||||
p.c_taxcategory_id,
|
p.isdropship,
|
||||||
p.c_uom_id AS m_productline_c_uom_id,
|
p.isexcludeautodelivery,
|
||||||
p.description AS m_product_description,
|
p.isinvoiceprintdetails,
|
||||||
p.descriptionurl,
|
p.ispicklistprintdetails,
|
||||||
p.discontinued,
|
p.ispurchased,
|
||||||
p.discontinuedat,
|
p.isselfservice,
|
||||||
p.documentnote,
|
p.issold,
|
||||||
p.group1,
|
p.isstocked,
|
||||||
p.group2,
|
p.issummary AS m_product_issummary,
|
||||||
p.guaranteedays,
|
p.isverified,
|
||||||
p.guaranteedaysmin,
|
p.iswebstorefeatured,
|
||||||
p.help,
|
p.lowlevel,
|
||||||
p.imageurl,
|
p.m_attributeset_id AS m_product_m_attributeset_id,
|
||||||
p.isactive AS m_product_isactive,
|
p.m_freightcategory_id,
|
||||||
p.isdropship,
|
p.m_locator_id,
|
||||||
p.isexcludeautodelivery,
|
p.m_product_id AS m_product_m_product_id,
|
||||||
p.isinvoiceprintdetails,
|
p.processing AS m_product_processing,
|
||||||
p.ispicklistprintdetails,
|
p.producttype,
|
||||||
p.ispurchased,
|
p.r_mailtext_id,
|
||||||
p.isselfservice,
|
p.salesrep_id AS m_product_salesrep_id,
|
||||||
p.issold,
|
p.s_expensetype_id,
|
||||||
p.isstocked,
|
p.shelfdepth,
|
||||||
p.issummary AS m_product_issummary,
|
p.shelfheight,
|
||||||
p.isverified,
|
p.shelfwidth,
|
||||||
p.iswebstorefeatured,
|
p.sku,
|
||||||
p.lowlevel,
|
p.s_resource_id,
|
||||||
p.m_attributeset_id AS m_product_m_attributeset_id,
|
p.unitsperpack,
|
||||||
p.m_freightcategory_id,
|
p.unitsperpallet,
|
||||||
p.m_locator_id,
|
p.updated AS m_product_updated,
|
||||||
p.m_product_id AS m_product_m_product_id,
|
p.updatedby AS m_product_updatedby,
|
||||||
p.processing AS m_product_processing,
|
p.versionno,
|
||||||
p.producttype,
|
p.volume,
|
||||||
p.r_mailtext_id,
|
p.weight,
|
||||||
p.salesrep_id AS m_product_salesrep_id,
|
pasi.ad_org_id AS m_asi_ad_org_id,
|
||||||
p.s_expensetype_id,
|
pasi.created AS m_attributesetinstance_created,
|
||||||
p.shelfdepth,
|
pasi.createdby AS m_asi_createdby,
|
||||||
p.shelfheight,
|
pasi.description AS m_asi_description,
|
||||||
p.shelfwidth,
|
pasi.isactive AS m_attributesetinstance_isacti,
|
||||||
p.sku,
|
pasi.serno AS m_attributesetinstance_serno,
|
||||||
p.s_resource_id,
|
pasi.updated AS m_attributesetinstance_updated,
|
||||||
p.unitsperpack,
|
pasi.updatedby AS m_asi_updatedby
|
||||||
p.unitsperpallet,
|
FROM rv_c_invoice i
|
||||||
p.updated AS m_product_updated,
|
JOIN c_invoiceline il
|
||||||
p.updatedby AS m_product_updatedby,
|
ON i.c_invoice_id = il.c_invoice_id
|
||||||
p.versionno,
|
LEFT JOIN m_product p
|
||||||
p.volume,
|
ON il.m_product_id = p.m_product_id
|
||||||
p.weight,
|
LEFT JOIN m_attributesetinstance pasi
|
||||||
pasi.ad_org_id AS m_asi_ad_org_id,
|
ON il.m_attributesetinstance_id = pasi.m_attributesetinstance_id
|
||||||
pasi.created AS m_attributesetinstance_created,
|
|
||||||
pasi.createdby AS m_asi_createdby,
|
|
||||||
pasi.description AS m_asi_description,
|
|
||||||
pasi.isactive AS m_attributesetinstance_isacti,
|
|
||||||
pasi.serno AS m_attributesetinstance_serno,
|
|
||||||
pasi.updated AS m_attributesetinstance_updated,
|
|
||||||
pasi.updatedby AS m_asi_updatedby
|
|
||||||
FROM rv_c_invoice i
|
|
||||||
JOIN c_invoiceline il
|
|
||||||
ON i.c_invoice_id = il.c_invoice_id
|
|
||||||
LEFT JOIN m_product p
|
|
||||||
ON il.m_product_id = p.m_product_id
|
|
||||||
LEFT JOIN m_attributesetinstance pasi
|
|
||||||
ON il.m_attributesetinstance_id = pasi.m_attributesetinstance_id
|
|
||||||
;
|
;
|
||||||
|
|
||||||
|
|
|
@ -11,14 +11,15 @@ SELECT il.AD_Client_ID, il.AD_Org_ID,
|
||||||
SUM(LineLimitAmt) AS LineLimitAmt,
|
SUM(LineLimitAmt) AS LineLimitAmt,
|
||||||
SUM(LineDiscountAmt) AS LineDiscountAmt,
|
SUM(LineDiscountAmt) AS LineDiscountAmt,
|
||||||
CASE WHEN SUM(LineListAmt)=0 THEN 0 ELSE
|
CASE WHEN SUM(LineListAmt)=0 THEN 0 ELSE
|
||||||
ROUND((SUM(LineListAmt)-SUM(LineNetAmt))/SUM(LineListAmt)*100,2) END AS LineDiscount,
|
currencyRound((SUM(LineListAmt)-SUM(LineNetAmt))/SUM(LineListAmt)*100,i.C_Currency_ID,'N') END AS LineDiscount,
|
||||||
SUM(LineOverLimitAmt) AS LineOverLimitAmt,
|
SUM(LineOverLimitAmt) AS LineOverLimitAmt,
|
||||||
CASE WHEN SUM(LineNetAmt)=0 THEN 0 ELSE
|
CASE WHEN SUM(LineNetAmt)=0 THEN 0 ELSE
|
||||||
100-ROUND((SUM(LineNetAmt)-SUM(LineOverLimitAmt))/SUM(LineNetAmt)*100,2) END AS LineOverLimit,
|
100-currencyRound((SUM(LineNetAmt)-SUM(LineOverLimitAmt))/SUM(LineNetAmt)*100,i.C_Currency_ID,'N') END AS LineOverLimit,
|
||||||
SUM(QtyInvoiced) AS QtyInvoiced, IsSOTrx
|
SUM(QtyInvoiced) AS QtyInvoiced, il.IsSOTrx
|
||||||
FROM RV_C_InvoiceLine il
|
FROM RV_C_InvoiceLine il
|
||||||
|
INNER JOIN C_Invoice i ON (i.C_Invoice_ID=il.C_Invoice_ID)
|
||||||
GROUP BY il.AD_Client_ID, il.AD_Org_ID, il.C_BPartner_ID, il.M_Product_Category_ID,
|
GROUP BY il.AD_Client_ID, il.AD_Org_ID, il.C_BPartner_ID, il.M_Product_Category_ID,
|
||||||
firstOf(il.DateInvoiced, 'Q'), IsSOTrx;
|
firstOf(il.DateInvoiced, 'Q'), il.IsSOTrx, i.C_Currency_ID;
|
||||||
|
|
||||||
|
|
||||||
|
|
||||||
|
|
|
@ -11,16 +11,17 @@ SELECT il.AD_Client_ID, il.AD_Org_ID,
|
||||||
SUM(LineLimitAmt) AS LineLimitAmt,
|
SUM(LineLimitAmt) AS LineLimitAmt,
|
||||||
SUM(LineDiscountAmt) AS LineDiscountAmt,
|
SUM(LineDiscountAmt) AS LineDiscountAmt,
|
||||||
CASE WHEN SUM(LineListAmt)=0 THEN 0 ELSE
|
CASE WHEN SUM(LineListAmt)=0 THEN 0 ELSE
|
||||||
ROUND((SUM(LineListAmt)-SUM(LineNetAmt))/SUM(LineListAmt)*100,2) END AS LineDiscount,
|
currencyRound((SUM(LineListAmt)-SUM(LineNetAmt))/SUM(LineListAmt)*100,i.C_Currency_ID,'N') END AS LineDiscount,
|
||||||
SUM(LineOverLimitAmt) AS LineOverLimitAmt,
|
SUM(LineOverLimitAmt) AS LineOverLimitAmt,
|
||||||
CASE WHEN SUM(LineNetAmt)=0 THEN 0 ELSE
|
CASE WHEN SUM(LineNetAmt)=0 THEN 0 ELSE
|
||||||
100-ROUND((SUM(LineNetAmt)-SUM(LineOverLimitAmt))/SUM(LineNetAmt)*100,2) END AS LineOverLimit,
|
100-currencyRound((SUM(LineNetAmt)-SUM(LineOverLimitAmt))/SUM(LineNetAmt)*100,i.C_Currency_ID,'N') END AS LineOverLimit,
|
||||||
SUM(QtyInvoiced) AS QtyInvoiced
|
SUM(QtyInvoiced) AS QtyInvoiced
|
||||||
FROM RV_C_InvoiceLine il
|
FROM RV_C_InvoiceLine il
|
||||||
INNER JOIN M_Product_PO po ON (il.M_Product_ID=po.M_Product_ID)
|
INNER JOIN C_Invoice i ON (i.C_Invoice_ID=il.C_Invoice_ID)
|
||||||
|
INNER JOIN M_Product_PO po ON (il.M_Product_ID=po.M_Product_ID)
|
||||||
WHERE il.IsSOTrx='Y'
|
WHERE il.IsSOTrx='Y'
|
||||||
GROUP BY il.AD_Client_ID, il.AD_Org_ID, il.C_BPartner_ID, po.C_BPartner_ID,
|
GROUP BY il.AD_Client_ID, il.AD_Org_ID, il.C_BPartner_ID, po.C_BPartner_ID,
|
||||||
firstOf(il.DateInvoiced, 'Q');
|
firstOf(il.DateInvoiced, 'Q'), i.C_Currency_ID;
|
||||||
|
|
||||||
|
|
||||||
|
|
||||||
|
|
|
@ -3,21 +3,22 @@ CREATE OR REPLACE VIEW RV_C_INVOICE_DAY
|
||||||
LINELISTAMT, LINELIMITAMT, LINEDISCOUNTAMT, LINEDISCOUNT, LINEOVERLIMITAMT,
|
LINELISTAMT, LINELIMITAMT, LINEDISCOUNTAMT, LINEDISCOUNT, LINEOVERLIMITAMT,
|
||||||
LINEOVERLIMIT, ISSOTRX)
|
LINEOVERLIMIT, ISSOTRX)
|
||||||
AS
|
AS
|
||||||
SELECT AD_Client_ID, AD_Org_ID, SalesRep_ID,
|
SELECT il.AD_Client_ID, il.AD_Org_ID, il.SalesRep_ID,
|
||||||
firstOf(DateInvoiced, 'DD') AS DateInvoiced, -- DD Day, DY Week, MM Month
|
firstOf(il.DateInvoiced, 'DD') AS DateInvoiced, -- DD Day, DY Week, MM Month
|
||||||
SUM(LineNetAmt) AS LineNetAmt,
|
SUM(LineNetAmt) AS LineNetAmt,
|
||||||
SUM(LineListAmt) AS LineListAmt,
|
SUM(LineListAmt) AS LineListAmt,
|
||||||
SUM(LineLimitAmt) AS LineLimitAmt,
|
SUM(LineLimitAmt) AS LineLimitAmt,
|
||||||
SUM(LineDiscountAmt) AS LineDiscountAmt,
|
SUM(LineDiscountAmt) AS LineDiscountAmt,
|
||||||
CASE WHEN SUM(LineListAmt)=0 THEN 0 ELSE
|
CASE WHEN SUM(LineListAmt)=0 THEN 0 ELSE
|
||||||
ROUND((SUM(LineListAmt)-SUM(LineNetAmt))/SUM(LineListAmt)*100,2) END AS LineDiscount,
|
currencyRound((SUM(LineListAmt)-SUM(LineNetAmt))/SUM(LineListAmt)*100,i.C_Currency_ID,'N') END AS LineDiscount,
|
||||||
SUM(LineOverLimitAmt) AS LineOverLimitAmt,
|
SUM(LineOverLimitAmt) AS LineOverLimitAmt,
|
||||||
CASE WHEN SUM(LineNetAmt)=0 THEN 0 ELSE
|
CASE WHEN SUM(LineNetAmt)=0 THEN 0 ELSE
|
||||||
100-ROUND((SUM(LineNetAmt)-SUM(LineOverLimitAmt))/SUM(LineNetAmt)*100,2) END AS LineOverLimit,
|
100-currencyRound((SUM(LineNetAmt)-SUM(LineOverLimitAmt))/SUM(LineNetAmt)*100,i.C_Currency_ID,'N') END AS LineOverLimit,
|
||||||
IsSOTrx
|
il.IsSOTrx
|
||||||
FROM RV_C_InvoiceLine
|
FROM RV_C_InvoiceLine il
|
||||||
GROUP BY AD_Client_ID, AD_Org_ID, SalesRep_ID,
|
INNER JOIN C_Invoice i ON (i.C_Invoice_ID=il.C_Invoice_ID)
|
||||||
firstOf(DateInvoiced, 'DD'), IsSOTrx;
|
GROUP BY il.AD_Client_ID, il.AD_Org_ID, il.SalesRep_ID,
|
||||||
|
firstOf(il.DateInvoiced, 'DD'), il.IsSOTrx, i.C_Currency_ID;
|
||||||
|
|
||||||
|
|
||||||
|
|
||||||
|
|
|
@ -3,21 +3,22 @@ CREATE OR REPLACE VIEW RV_C_INVOICE_MONTH
|
||||||
LINELISTAMT, LINELIMITAMT, LINEDISCOUNTAMT, LINEDISCOUNT, LINEOVERLIMITAMT,
|
LINELISTAMT, LINELIMITAMT, LINEDISCOUNTAMT, LINEDISCOUNT, LINEOVERLIMITAMT,
|
||||||
LINEOVERLIMIT, ISSOTRX)
|
LINEOVERLIMIT, ISSOTRX)
|
||||||
AS
|
AS
|
||||||
SELECT AD_Client_ID, AD_Org_ID, SalesRep_ID,
|
SELECT il.AD_Client_ID, il.AD_Org_ID, il.SalesRep_ID,
|
||||||
firstOf(DateInvoiced, 'MM') AS DateInvoiced, -- DD Day, DY Week, MM Month
|
firstOf(il.DateInvoiced, 'MM') AS DateInvoiced, -- DD Day, DY Week, MM Month
|
||||||
SUM(LineNetAmt) AS LineNetAmt,
|
SUM(LineNetAmt) AS LineNetAmt,
|
||||||
SUM(LineListAmt) AS LineListAmt,
|
SUM(LineListAmt) AS LineListAmt,
|
||||||
SUM(LineLimitAmt) AS LineLimitAmt,
|
SUM(LineLimitAmt) AS LineLimitAmt,
|
||||||
SUM(LineDiscountAmt) AS LineDiscountAmt,
|
SUM(LineDiscountAmt) AS LineDiscountAmt,
|
||||||
CASE WHEN SUM(LineListAmt)=0 THEN 0 ELSE
|
CASE WHEN SUM(LineListAmt)=0 THEN 0 ELSE
|
||||||
ROUND((SUM(LineListAmt)-SUM(LineNetAmt))/SUM(LineListAmt)*100,2) END AS LineDiscount,
|
currencyRound((SUM(LineListAmt)-SUM(LineNetAmt))/SUM(LineListAmt)*100,i.C_Currency_ID,'N') END AS LineDiscount,
|
||||||
SUM(LineOverLimitAmt) AS LineOverLimitAmt,
|
SUM(LineOverLimitAmt) AS LineOverLimitAmt,
|
||||||
CASE WHEN SUM(LineNetAmt)=0 THEN 0 ELSE
|
CASE WHEN SUM(LineNetAmt)=0 THEN 0 ELSE
|
||||||
100-ROUND((SUM(LineNetAmt)-SUM(LineOverLimitAmt))/SUM(LineNetAmt)*100,2) END AS LineOverLimit,
|
100-currencyRound((SUM(LineNetAmt)-SUM(LineOverLimitAmt))/SUM(LineNetAmt)*100,i.C_Currency_ID,'N') END AS LineOverLimit,
|
||||||
IsSOTrx
|
il.IsSOTrx
|
||||||
FROM RV_C_InvoiceLine
|
FROM RV_C_InvoiceLine il
|
||||||
GROUP BY AD_Client_ID, AD_Org_ID, SalesRep_ID,
|
INNER JOIN C_Invoice i ON (i.C_Invoice_ID=il.C_Invoice_ID)
|
||||||
firstOf(DateInvoiced, 'MM'), IsSOTrx;
|
GROUP BY il.AD_Client_ID, il.AD_Org_ID, il.SalesRep_ID,
|
||||||
|
firstOf(il.DateInvoiced, 'MM'), il.IsSOTrx, i.C_Currency_ID;
|
||||||
|
|
||||||
|
|
||||||
|
|
||||||
|
|
|
@ -10,14 +10,15 @@ SELECT il.AD_Client_ID, il.AD_Org_ID, il.M_Product_Category_ID,
|
||||||
SUM(il.LineLimitAmt) AS LineLimitAmt,
|
SUM(il.LineLimitAmt) AS LineLimitAmt,
|
||||||
SUM(il.LineDiscountAmt) AS LineDiscountAmt,
|
SUM(il.LineDiscountAmt) AS LineDiscountAmt,
|
||||||
CASE WHEN SUM(LineListAmt)=0 THEN 0 ELSE
|
CASE WHEN SUM(LineListAmt)=0 THEN 0 ELSE
|
||||||
ROUND((SUM(LineListAmt)-SUM(LineNetAmt))/SUM(LineListAmt)*100,2) END AS LineDiscount,
|
currencyRound((SUM(LineListAmt)-SUM(LineNetAmt))/SUM(LineListAmt)*100,i.C_Currency_ID,'N') END AS LineDiscount,
|
||||||
SUM(LineOverLimitAmt) AS LineOverLimitAmt,
|
SUM(LineOverLimitAmt) AS LineOverLimitAmt,
|
||||||
CASE WHEN SUM(LineNetAmt)=0 THEN 0 ELSE
|
CASE WHEN SUM(LineNetAmt)=0 THEN 0 ELSE
|
||||||
100-ROUND((SUM(LineNetAmt)-SUM(LineOverLimitAmt))/SUM(LineNetAmt)*100,2) END AS LineOverLimit,
|
100-currencyRound((SUM(LineNetAmt)-SUM(LineOverLimitAmt))/SUM(LineNetAmt)*100,i.C_Currency_ID,'N') END AS LineOverLimit,
|
||||||
SUM(QtyInvoiced) AS QtyInvoiced, IsSOTrx
|
SUM(QtyInvoiced) AS QtyInvoiced, il.IsSOTrx
|
||||||
FROM RV_C_InvoiceLine il
|
FROM RV_C_InvoiceLine il
|
||||||
|
INNER JOIN C_Invoice i ON (i.C_Invoice_ID=il.C_Invoice_ID)
|
||||||
GROUP BY il.AD_Client_ID, il.AD_Org_ID, il.M_Product_Category_ID,
|
GROUP BY il.AD_Client_ID, il.AD_Org_ID, il.M_Product_Category_ID,
|
||||||
firstOf(il.DateInvoiced, 'MM'), IsSOTrx;
|
firstOf(il.DateInvoiced, 'MM'), il.IsSOTrx, i.C_Currency_ID;
|
||||||
|
|
||||||
|
|
||||||
|
|
||||||
|
|
|
@ -10,14 +10,15 @@ SELECT il.AD_Client_ID, il.AD_Org_ID, il.M_Product_ID,
|
||||||
SUM(il.LineLimitAmt) AS LineLimitAmt,
|
SUM(il.LineLimitAmt) AS LineLimitAmt,
|
||||||
SUM(il.LineDiscountAmt) AS LineDiscountAmt,
|
SUM(il.LineDiscountAmt) AS LineDiscountAmt,
|
||||||
CASE WHEN SUM(LineListAmt)=0 THEN 0 ELSE
|
CASE WHEN SUM(LineListAmt)=0 THEN 0 ELSE
|
||||||
ROUND((SUM(LineListAmt)-SUM(LineNetAmt))/SUM(LineListAmt)*100,2) END AS LineDiscount,
|
currencyRound((SUM(LineListAmt)-SUM(LineNetAmt))/SUM(LineListAmt)*100,i.C_Currency_ID,'N') END AS LineDiscount,
|
||||||
SUM(LineOverLimitAmt) AS LineOverLimitAmt,
|
SUM(LineOverLimitAmt) AS LineOverLimitAmt,
|
||||||
CASE WHEN SUM(LineNetAmt)=0 THEN 0 ELSE
|
CASE WHEN SUM(LineNetAmt)=0 THEN 0 ELSE
|
||||||
100-ROUND((SUM(LineNetAmt)-SUM(LineOverLimitAmt))/SUM(LineNetAmt)*100,2) END AS LineOverLimit,
|
100-currencyRound((SUM(LineNetAmt)-SUM(LineOverLimitAmt))/SUM(LineNetAmt)*100,i.C_Currency_ID,'N') END AS LineOverLimit,
|
||||||
SUM(QtyInvoiced) AS QtyInvoiced, IsSOTrx
|
SUM(QtyInvoiced) AS QtyInvoiced, il.IsSOTrx
|
||||||
FROM RV_C_InvoiceLine il
|
FROM RV_C_InvoiceLine il
|
||||||
|
INNER JOIN C_Invoice i ON (i.C_Invoice_ID=il.C_Invoice_ID)
|
||||||
GROUP BY il.AD_Client_ID, il.AD_Org_ID, il.M_Product_ID,
|
GROUP BY il.AD_Client_ID, il.AD_Org_ID, il.M_Product_ID,
|
||||||
firstOf(il.DateInvoiced, 'MM'), IsSOTrx;
|
firstOf(il.DateInvoiced, 'MM'), il.IsSOTrx, i.C_Currency_ID;
|
||||||
|
|
||||||
|
|
||||||
|
|
||||||
|
|
|
@ -10,14 +10,15 @@ SELECT il.AD_Client_ID, il.AD_Org_ID, il.M_Product_ID,
|
||||||
SUM(il.LineLimitAmt) AS LineLimitAmt,
|
SUM(il.LineLimitAmt) AS LineLimitAmt,
|
||||||
SUM(il.LineDiscountAmt) AS LineDiscountAmt,
|
SUM(il.LineDiscountAmt) AS LineDiscountAmt,
|
||||||
CASE WHEN SUM(LineListAmt)=0 THEN 0 ELSE
|
CASE WHEN SUM(LineListAmt)=0 THEN 0 ELSE
|
||||||
ROUND((SUM(LineListAmt)-SUM(LineNetAmt))/SUM(LineListAmt)*100,2) END AS LineDiscount,
|
currencyRound((SUM(LineListAmt)-SUM(LineNetAmt))/SUM(LineListAmt)*100,i.C_Currency_ID,'N') END AS LineDiscount,
|
||||||
SUM(LineOverLimitAmt) AS LineOverLimitAmt,
|
SUM(LineOverLimitAmt) AS LineOverLimitAmt,
|
||||||
CASE WHEN SUM(LineNetAmt)=0 THEN 0 ELSE
|
CASE WHEN SUM(LineNetAmt)=0 THEN 0 ELSE
|
||||||
100-ROUND((SUM(LineNetAmt)-SUM(LineOverLimitAmt))/SUM(LineNetAmt)*100,2) END AS LineOverLimit,
|
100-currencyRound((SUM(LineNetAmt)-SUM(LineOverLimitAmt))/SUM(LineNetAmt)*100,i.C_Currency_ID,'N') END AS LineOverLimit,
|
||||||
SUM(QtyInvoiced) AS QtyInvoiced, IsSOTrx
|
SUM(QtyInvoiced) AS QtyInvoiced, il.IsSOTrx
|
||||||
FROM RV_C_InvoiceLine il
|
FROM RV_C_InvoiceLine il
|
||||||
|
INNER JOIN C_Invoice i ON (i.C_Invoice_ID=il.C_Invoice_ID)
|
||||||
GROUP BY il.AD_Client_ID, il.AD_Org_ID, il.M_Product_ID,
|
GROUP BY il.AD_Client_ID, il.AD_Org_ID, il.M_Product_ID,
|
||||||
firstOf(il.DateInvoiced, 'Q'), IsSOTrx;
|
firstOf(il.DateInvoiced, 'Q'), il.IsSOTrx, i.C_Currency_ID;
|
||||||
|
|
||||||
|
|
||||||
|
|
||||||
|
|
|
@ -10,14 +10,15 @@ SELECT il.AD_Client_ID, il.AD_Org_ID, il.M_Product_Category_ID,
|
||||||
SUM(il.LineLimitAmt) AS LineLimitAmt,
|
SUM(il.LineLimitAmt) AS LineLimitAmt,
|
||||||
SUM(il.LineDiscountAmt) AS LineDiscountAmt,
|
SUM(il.LineDiscountAmt) AS LineDiscountAmt,
|
||||||
CASE WHEN SUM(LineListAmt)=0 THEN 0 ELSE
|
CASE WHEN SUM(LineListAmt)=0 THEN 0 ELSE
|
||||||
ROUND((SUM(LineListAmt)-SUM(LineNetAmt))/SUM(LineListAmt)*100,2) END AS LineDiscount,
|
currencyRound((SUM(LineListAmt)-SUM(LineNetAmt))/SUM(LineListAmt)*100,i.C_Currency_ID,'N') END AS LineDiscount,
|
||||||
SUM(LineOverLimitAmt) AS LineOverLimitAmt,
|
SUM(LineOverLimitAmt) AS LineOverLimitAmt,
|
||||||
CASE WHEN SUM(LineNetAmt)=0 THEN 0 ELSE
|
CASE WHEN SUM(LineNetAmt)=0 THEN 0 ELSE
|
||||||
100-ROUND((SUM(LineNetAmt)-SUM(LineOverLimitAmt))/SUM(LineNetAmt)*100,2) END AS LineOverLimit,
|
100-currencyRound((SUM(LineNetAmt)-SUM(LineOverLimitAmt))/SUM(LineNetAmt)*100,i.C_Currency_ID,'N') END AS LineOverLimit,
|
||||||
SUM(QtyInvoiced) AS QtyInvoiced, IsSOTrx
|
SUM(QtyInvoiced) AS QtyInvoiced, il.IsSOTrx
|
||||||
FROM RV_C_InvoiceLine il
|
FROM RV_C_InvoiceLine il
|
||||||
|
INNER JOIN C_Invoice i ON (i.C_Invoice_ID=il.C_Invoice_ID)
|
||||||
GROUP BY il.AD_Client_ID, il.AD_Org_ID, il.M_Product_Category_ID,
|
GROUP BY il.AD_Client_ID, il.AD_Org_ID, il.M_Product_Category_ID,
|
||||||
firstOf(il.DateInvoiced, 'DY'), IsSOTrx;
|
firstOf(il.DateInvoiced, 'DY'), il.IsSOTrx, i.C_Currency_ID;
|
||||||
|
|
||||||
|
|
||||||
|
|
||||||
|
|
|
@ -6,21 +6,22 @@ AS
|
||||||
SELECT il.AD_Client_ID, il.AD_Org_ID,
|
SELECT il.AD_Client_ID, il.AD_Org_ID,
|
||||||
po.C_BPartner_ID, il.M_Product_Category_ID,
|
po.C_BPartner_ID, il.M_Product_Category_ID,
|
||||||
firstOf(il.DateInvoiced, 'MM') AS DateInvoiced, -- DD Day, DY Week, MM Month
|
firstOf(il.DateInvoiced, 'MM') AS DateInvoiced, -- DD Day, DY Week, MM Month
|
||||||
SUM(LineNetAmt) AS LineNetAmt,
|
SUM(il.LineNetAmt) AS LineNetAmt,
|
||||||
SUM(LineListAmt) AS LineListAmt,
|
SUM(LineListAmt) AS LineListAmt,
|
||||||
SUM(LineLimitAmt) AS LineLimitAmt,
|
SUM(LineLimitAmt) AS LineLimitAmt,
|
||||||
SUM(LineDiscountAmt) AS LineDiscountAmt,
|
SUM(LineDiscountAmt) AS LineDiscountAmt,
|
||||||
CASE WHEN SUM(LineListAmt)=0 THEN 0 ELSE
|
CASE WHEN SUM(LineListAmt)=0 THEN 0 ELSE
|
||||||
ROUND((SUM(LineListAmt)-SUM(LineNetAmt))/SUM(LineListAmt)*100,2) END AS LineDiscount,
|
currencyRound((SUM(LineListAmt)-SUM(LineNetAmt))/SUM(LineListAmt)*100,i.C_Currency_ID,'N') END AS LineDiscount,
|
||||||
SUM(LineOverLimitAmt) AS LineOverLimitAmt,
|
SUM(LineOverLimitAmt) AS LineOverLimitAmt,
|
||||||
CASE WHEN SUM(LineNetAmt)=0 THEN 0 ELSE
|
CASE WHEN SUM(LineNetAmt)=0 THEN 0 ELSE
|
||||||
100-ROUND((SUM(LineNetAmt)-SUM(LineOverLimitAmt))/SUM(LineNetAmt)*100,2) END AS LineOverLimit,
|
100-currencyRound((SUM(LineNetAmt)-SUM(LineOverLimitAmt))/SUM(LineNetAmt)*100,i.C_Currency_ID,'N') END AS LineOverLimit,
|
||||||
SUM(QtyInvoiced) AS QtyInvoiced
|
SUM(QtyInvoiced) AS QtyInvoiced
|
||||||
FROM RV_C_InvoiceLine il
|
FROM RV_C_InvoiceLine il
|
||||||
|
INNER JOIN C_Invoice i ON (i.C_Invoice_ID=il.C_Invoice_ID)
|
||||||
INNER JOIN M_Product_PO po ON (il.M_Product_ID=po.M_Product_ID)
|
INNER JOIN M_Product_PO po ON (il.M_Product_ID=po.M_Product_ID)
|
||||||
WHERE il.IsSOTrx='Y'
|
WHERE il.IsSOTrx='Y'
|
||||||
GROUP BY il.AD_Client_ID, il.AD_Org_ID, po.C_BPartner_ID, il.M_Product_Category_ID,
|
GROUP BY il.AD_Client_ID, il.AD_Org_ID, po.C_BPartner_ID, il.M_Product_Category_ID,
|
||||||
firstOf(il.DateInvoiced, 'MM');
|
firstOf(il.DateInvoiced, 'MM'), i.C_Currency_ID;
|
||||||
|
|
||||||
|
|
||||||
|
|
||||||
|
|
|
@ -3,21 +3,22 @@ CREATE OR REPLACE VIEW RV_C_INVOICE_WEEK
|
||||||
LINELISTAMT, LINELIMITAMT, LINEDISCOUNTAMT, LINEDISCOUNT, LINEOVERLIMITAMT,
|
LINELISTAMT, LINELIMITAMT, LINEDISCOUNTAMT, LINEDISCOUNT, LINEOVERLIMITAMT,
|
||||||
LINEOVERLIMIT, ISSOTRX)
|
LINEOVERLIMIT, ISSOTRX)
|
||||||
AS
|
AS
|
||||||
SELECT AD_Client_ID, AD_Org_ID, SalesRep_ID,
|
SELECT il.AD_Client_ID, il.AD_Org_ID, il.SalesRep_ID,
|
||||||
firstOf(DateInvoiced, 'DY') AS DateInvoiced, -- DD Day, DY Week, MM Month
|
firstOf(il.DateInvoiced, 'DY') AS DateInvoiced, -- DD Day, DY Week, MM Month
|
||||||
SUM(LineNetAmt) AS LineNetAmt,
|
SUM(LineNetAmt) AS LineNetAmt,
|
||||||
SUM(LineListAmt) AS LineListAmt,
|
SUM(LineListAmt) AS LineListAmt,
|
||||||
SUM(LineLimitAmt) AS LineLimitAmt,
|
SUM(LineLimitAmt) AS LineLimitAmt,
|
||||||
SUM(LineDiscountAmt) AS LineDiscountAmt,
|
SUM(LineDiscountAmt) AS LineDiscountAmt,
|
||||||
CASE WHEN SUM(LineListAmt)=0 THEN 0 ELSE
|
CASE WHEN SUM(LineListAmt)=0 THEN 0 ELSE
|
||||||
ROUND((SUM(LineListAmt)-SUM(LineNetAmt))/SUM(LineListAmt)*100,2) END AS LineDiscount,
|
currencyRound((SUM(LineListAmt)-SUM(LineNetAmt))/SUM(LineListAmt)*100,i.C_Currency_ID,'N') END AS LineDiscount,
|
||||||
SUM(LineOverLimitAmt) AS LineOverLimitAmt,
|
SUM(LineOverLimitAmt) AS LineOverLimitAmt,
|
||||||
CASE WHEN SUM(LineNetAmt)=0 THEN 0 ELSE
|
CASE WHEN SUM(LineNetAmt)=0 THEN 0 ELSE
|
||||||
100-ROUND((SUM(LineNetAmt)-SUM(LineOverLimitAmt))/SUM(LineNetAmt)*100,2) END AS LineOverLimit,
|
100-currencyRound((SUM(LineNetAmt)-SUM(LineOverLimitAmt))/SUM(LineNetAmt)*100,i.C_Currency_ID,'N') END AS LineOverLimit,
|
||||||
IsSOTrx
|
il.IsSOTrx
|
||||||
FROM RV_C_InvoiceLine
|
FROM RV_C_InvoiceLine il
|
||||||
GROUP BY AD_Client_ID, AD_Org_ID, SalesRep_ID,
|
INNER JOIN C_Invoice i ON (i.C_Invoice_ID=il.C_Invoice_ID)
|
||||||
firstOf(DateInvoiced, 'DY'), IsSOTrx;
|
GROUP BY il.AD_Client_ID, il.AD_Org_ID, il.SalesRep_ID,
|
||||||
|
firstOf(il.DateInvoiced, 'DY'), il.IsSOTrx, i.C_Currency_ID;
|
||||||
|
|
||||||
|
|
||||||
|
|
||||||
|
|
|
@ -1,158 +1,153 @@
|
||||||
DROP VIEW rv_openitem;
|
DROP VIEW rv_openitem;
|
||||||
|
|
||||||
CREATE OR REPLACE VIEW rv_openitem
|
CREATE OR REPLACE VIEW rv_openitem AS
|
||||||
AS
|
SELECT i.ad_org_id,
|
||||||
SELECT i.ad_org_id,
|
i.ad_client_id,
|
||||||
i.ad_client_id,
|
i.documentno,
|
||||||
i.documentno,
|
i.c_invoice_id,
|
||||||
i.c_invoice_id,
|
i.c_order_id,
|
||||||
i.c_order_id,
|
i.c_bpartner_id,
|
||||||
i.c_bpartner_id,
|
i.issotrx,
|
||||||
i.issotrx,
|
i.dateinvoiced,
|
||||||
i.dateinvoiced,
|
i.dateacct,
|
||||||
i.dateacct,
|
p.netdays,
|
||||||
p.netdays,
|
paymenttermduedate(i.c_paymentterm_id, i.dateinvoiced) AS duedate,
|
||||||
paymenttermduedate(i.c_paymentterm_id, i.dateinvoiced) AS duedate,
|
paymenttermduedays(i.c_paymentterm_id, i.dateinvoiced, getdate()) AS daysdue,
|
||||||
paymenttermduedays(i.c_paymentterm_id, i.dateinvoiced, getdate()) AS daysdue,
|
adddays(i.dateinvoiced, p.discountdays) AS discountdate,
|
||||||
adddays(i.dateinvoiced, p.discountdays) AS discountdate,
|
currencyRound(i.grandtotal * p.discount / 100,i.C_Currency_ID,'N') AS discountamt,
|
||||||
round(i.grandtotal * p.discount / 100, 2) AS discountamt,
|
i.grandtotal,
|
||||||
i.grandtotal,
|
invoicepaid(i.c_invoice_id, i.c_currency_id, 1) AS paidamt,
|
||||||
invoicepaid(i.c_invoice_id, i.c_currency_id, 1) AS paidamt,
|
invoiceopen(i.c_invoice_id, 0) AS openamt,
|
||||||
invoiceopen(i.c_invoice_id, 0) AS openamt,
|
i.c_currency_id,
|
||||||
i.c_currency_id,
|
i.c_conversiontype_id,
|
||||||
i.c_conversiontype_id,
|
i.c_paymentterm_id,
|
||||||
i.c_paymentterm_id,
|
i.ispayschedulevalid,
|
||||||
i.ispayschedulevalid,
|
NULL AS c_invoicepayschedule_id,
|
||||||
NULL AS c_invoicepayschedule_id,
|
i.invoicecollectiontype,
|
||||||
i.invoicecollectiontype,
|
i.c_campaign_id,
|
||||||
i.c_campaign_id,
|
i.c_project_id,
|
||||||
i.c_project_id,
|
i.c_activity_id,
|
||||||
i.c_activity_id,
|
i.c_invoice_ad_orgtrx_id AS ad_orgtrx_id,
|
||||||
i.c_invoice_ad_orgtrx_id AS ad_orgtrx_id,
|
i.ad_user_id,
|
||||||
i.ad_user_id,
|
i.c_bpartner_location_id,
|
||||||
i.c_bpartner_location_id,
|
i.c_charge_id,
|
||||||
i.c_charge_id,
|
i.c_doctype_id,
|
||||||
i.c_doctype_id,
|
i.c_doctypetarget_id,
|
||||||
i.c_doctypetarget_id,
|
i.c_dunninglevel_id,
|
||||||
i.c_dunninglevel_id,
|
i.chargeamt,
|
||||||
i.chargeamt,
|
i.c_payment_id,
|
||||||
i.c_payment_id,
|
i.created,
|
||||||
i.created,
|
i.createdby,
|
||||||
i.createdby,
|
i.dateordered,
|
||||||
i.dateordered,
|
i.dateprinted,
|
||||||
i.dateprinted,
|
i.description,
|
||||||
i.description,
|
i.docaction,
|
||||||
i.docaction,
|
i.docstatus,
|
||||||
i.docstatus,
|
i.dunninggrace,
|
||||||
i.dunninggrace,
|
i.generateto,
|
||||||
i.generateto,
|
i.isactive,
|
||||||
i.isactive,
|
i.isapproved,
|
||||||
i.isapproved,
|
i.isdiscountprinted,
|
||||||
i.isdiscountprinted,
|
i.isindispute,
|
||||||
i.isindispute,
|
i.ispaid,
|
||||||
i.ispaid,
|
i.isprinted,
|
||||||
i.isprinted,
|
i.c_invoice_isselfservice AS isselfservice,
|
||||||
i.c_invoice_isselfservice AS isselfservice,
|
i.istaxincluded,
|
||||||
i.istaxincluded,
|
i.istransferred,
|
||||||
i.istransferred,
|
i.m_pricelist_id,
|
||||||
i.m_pricelist_id,
|
i.m_rma_id,
|
||||||
i.m_rma_id,
|
i.paymentrule,
|
||||||
i.paymentrule,
|
i.poreference,
|
||||||
i.poreference,
|
i.posted,
|
||||||
i.posted,
|
i.processedon,
|
||||||
i.processedon,
|
i.processing,
|
||||||
i.processing,
|
i.ref_invoice_id,
|
||||||
i.ref_invoice_id,
|
i.reversal_id,
|
||||||
i.reversal_id,
|
i.salesrep_id,
|
||||||
i.salesrep_id,
|
i.sendemail,
|
||||||
i.sendemail,
|
i.totallines,
|
||||||
i.totallines,
|
i.updated,
|
||||||
i.updated,
|
i.updatedby,
|
||||||
i.updatedby,
|
i.user1_id,
|
||||||
i.user1_id,
|
i.user2_id
|
||||||
i.user2_id
|
FROM rv_c_invoice i
|
||||||
FROM rv_c_invoice i
|
JOIN c_paymentterm p
|
||||||
JOIN c_paymentterm p
|
ON i.c_paymentterm_id = p.c_paymentterm_id
|
||||||
ON i.c_paymentterm_id = p.c_paymentterm_id
|
WHERE invoiceopen(i.c_invoice_id, 0) <> 0 AND i.ispayschedulevalid <> 'Y' AND i.docstatus IN ('CO',
|
||||||
WHERE invoiceopen(i.c_invoice_id, 0) <> 0
|
'CL')
|
||||||
AND i.ispayschedulevalid <> 'Y'
|
UNION
|
||||||
AND i.docstatus IN ( 'CO', 'CL' )
|
SELECT i.ad_org_id,
|
||||||
UNION
|
i.ad_client_id,
|
||||||
SELECT i.ad_org_id,
|
i.documentno,
|
||||||
i.ad_client_id,
|
i.c_invoice_id,
|
||||||
i.documentno,
|
i.c_order_id,
|
||||||
i.c_invoice_id,
|
i.c_bpartner_id,
|
||||||
i.c_order_id,
|
i.issotrx,
|
||||||
i.c_bpartner_id,
|
i.dateinvoiced,
|
||||||
i.issotrx,
|
i.dateacct,
|
||||||
i.dateinvoiced,
|
daysbetween(ips.duedate, i.dateinvoiced) AS netdays,
|
||||||
i.dateacct,
|
ips.duedate,
|
||||||
daysbetween(ips.duedate, i.dateinvoiced) AS netdays,
|
daysbetween(getdate(), ips.duedate) AS daysdue,
|
||||||
ips.duedate,
|
ips.discountdate,
|
||||||
daysbetween(getdate(), ips.duedate) AS daysdue,
|
ips.discountamt,
|
||||||
ips.discountdate,
|
ips.dueamt AS grandtotal,
|
||||||
ips.discountamt,
|
invoicepaid(i.c_invoice_id, i.c_currency_id, 1) AS paidamt,
|
||||||
ips.dueamt AS grandtotal,
|
invoiceopen(i.c_invoice_id, ips.c_invoicepayschedule_id) AS openamt,
|
||||||
invoicepaid(i.c_invoice_id, i.c_currency_id, 1) AS paidamt,
|
i.c_currency_id,
|
||||||
invoiceopen(i.c_invoice_id, ips.c_invoicepayschedule_id) AS openamt,
|
i.c_conversiontype_id,
|
||||||
i.c_currency_id,
|
i.c_paymentterm_id,
|
||||||
i.c_conversiontype_id,
|
i.ispayschedulevalid,
|
||||||
i.c_paymentterm_id,
|
ips.c_invoicepayschedule_id,
|
||||||
i.ispayschedulevalid,
|
i.invoicecollectiontype,
|
||||||
ips.c_invoicepayschedule_id,
|
i.c_campaign_id,
|
||||||
i.invoicecollectiontype,
|
i.c_project_id,
|
||||||
i.c_campaign_id,
|
i.c_activity_id,
|
||||||
i.c_project_id,
|
i.c_invoice_ad_orgtrx_id AS ad_orgtrx_id,
|
||||||
i.c_activity_id,
|
i.ad_user_id,
|
||||||
i.c_invoice_ad_orgtrx_id AS ad_orgtrx_id,
|
i.c_bpartner_location_id,
|
||||||
i.ad_user_id,
|
i.c_charge_id,
|
||||||
i.c_bpartner_location_id,
|
i.c_doctype_id,
|
||||||
i.c_charge_id,
|
i.c_doctypetarget_id,
|
||||||
i.c_doctype_id,
|
i.c_dunninglevel_id,
|
||||||
i.c_doctypetarget_id,
|
i.chargeamt,
|
||||||
i.c_dunninglevel_id,
|
i.c_payment_id,
|
||||||
i.chargeamt,
|
i.created,
|
||||||
i.c_payment_id,
|
i.createdby,
|
||||||
i.created,
|
i.dateordered,
|
||||||
i.createdby,
|
i.dateprinted,
|
||||||
i.dateordered,
|
i.description,
|
||||||
i.dateprinted,
|
i.docaction,
|
||||||
i.description,
|
i.docstatus,
|
||||||
i.docaction,
|
i.dunninggrace,
|
||||||
i.docstatus,
|
i.generateto,
|
||||||
i.dunninggrace,
|
i.isactive,
|
||||||
i.generateto,
|
i.isapproved,
|
||||||
i.isactive,
|
i.isdiscountprinted,
|
||||||
i.isapproved,
|
i.isindispute,
|
||||||
i.isdiscountprinted,
|
i.ispaid,
|
||||||
i.isindispute,
|
i.isprinted,
|
||||||
i.ispaid,
|
i.c_invoice_isselfservice AS isselfservice,
|
||||||
i.isprinted,
|
i.istaxincluded,
|
||||||
i.c_invoice_isselfservice AS isselfservice,
|
i.istransferred,
|
||||||
i.istaxincluded,
|
i.m_pricelist_id,
|
||||||
i.istransferred,
|
i.m_rma_id,
|
||||||
i.m_pricelist_id,
|
i.paymentrule,
|
||||||
i.m_rma_id,
|
i.poreference,
|
||||||
i.paymentrule,
|
i.posted,
|
||||||
i.poreference,
|
i.processedon,
|
||||||
i.posted,
|
i.processing,
|
||||||
i.processedon,
|
i.ref_invoice_id,
|
||||||
i.processing,
|
i.reversal_id,
|
||||||
i.ref_invoice_id,
|
i.salesrep_id,
|
||||||
i.reversal_id,
|
i.sendemail,
|
||||||
i.salesrep_id,
|
i.totallines,
|
||||||
i.sendemail,
|
i.updated,
|
||||||
i.totallines,
|
i.updatedby,
|
||||||
i.updated,
|
i.user1_id,
|
||||||
i.updatedby,
|
i.user2_id
|
||||||
i.user1_id,
|
FROM rv_c_invoice i
|
||||||
i.user2_id
|
JOIN c_invoicepayschedule ips
|
||||||
FROM rv_c_invoice i
|
ON i.c_invoice_id = ips.c_invoice_id
|
||||||
JOIN c_invoicepayschedule ips
|
WHERE invoiceopen(i.c_invoice_id, ips.c_invoicepayschedule_id) <> 0 AND i.ispayschedulevalid = 'Y' AND i.docstatus IN ('CO',
|
||||||
ON i.c_invoice_id = ips.c_invoice_id
|
'CL') AND ips.isvalid = 'Y'
|
||||||
WHERE invoiceopen(i.c_invoice_id, ips.c_invoicepayschedule_id) <> 0
|
|
||||||
AND i.ispayschedulevalid = 'Y'
|
|
||||||
AND i.docstatus IN ( 'CO', 'CL' )
|
|
||||||
AND ips.isvalid = 'Y'
|
|
||||||
;
|
;
|
||||||
|
|
||||||
|
|
|
@ -14,20 +14,19 @@ SELECT i.AD_Org_ID, i.AD_Client_ID,
|
||||||
paymentTermDueDate(i.C_PaymentTerm_ID, i.DateInvoiced) AS DueDate,
|
paymentTermDueDate(i.C_PaymentTerm_ID, i.DateInvoiced) AS DueDate,
|
||||||
paymentTermDueDays(i.C_PaymentTerm_ID, i.DateInvoiced, getdate()) AS DaysDue,
|
paymentTermDueDays(i.C_PaymentTerm_ID, i.DateInvoiced, getdate()) AS DaysDue,
|
||||||
addDays(i.DateInvoiced,p.DiscountDays) AS DiscountDate,
|
addDays(i.DateInvoiced,p.DiscountDays) AS DiscountDate,
|
||||||
ROUND(i.GrandTotal*p.Discount/100,2) AS DiscountAmt,
|
currencyRound(i.GrandTotal*p.Discount/100,i.C_Currency_ID,'N') AS DiscountAmt,
|
||||||
i.GrandTotal,
|
i.GrandTotal,
|
||||||
--invoicePaid(i.C_Invoice_ID, i.C_Currency_ID, 1) AS PaidAmt,
|
--invoicePaid(i.C_Invoice_ID, i.C_Currency_ID, 1) AS PaidAmt,
|
||||||
--invoiceOpen(i.C_Invoice_ID,0) AS OpenAmt,
|
--invoiceOpen(i.C_Invoice_ID,0) AS OpenAmt,
|
||||||
i.C_Currency_ID, i.C_ConversionType_ID,
|
i.C_Currency_ID, i.C_ConversionType_ID,
|
||||||
i.C_PaymentTerm_ID,
|
i.C_PaymentTerm_ID,
|
||||||
i.IsPayScheduleValid, cast(null as number) AS C_InvoicePaySchedule_ID, i.InvoiceCollectionType,
|
i.IsPayScheduleValid, cast(null as numeric) AS C_InvoicePaySchedule_ID, i.InvoiceCollectionType,
|
||||||
i.C_Campaign_ID, i.C_Project_ID, i.C_Activity_ID
|
i.C_Campaign_ID, i.C_Project_ID, i.C_Activity_ID
|
||||||
FROM RV_C_Invoice i
|
FROM RV_C_Invoice i
|
||||||
INNER JOIN C_PaymentTerm p ON (i.C_PaymentTerm_ID=p.C_PaymentTerm_ID)
|
INNER JOIN C_PaymentTerm p ON (i.C_PaymentTerm_ID=p.C_PaymentTerm_ID)
|
||||||
WHERE -- i.IsPaid='N'
|
WHERE -- i.IsPaid='N'
|
||||||
--invoiceOpen(i.C_Invoice_ID,0) <> 0 AND
|
--invoiceOpen(i.C_Invoice_ID,0) <> 0 AND
|
||||||
i.IsPayScheduleValid<>'Y'
|
i.IsPayScheduleValid<>'Y'
|
||||||
AND i.DocStatus<>'DR'
|
|
||||||
AND i.DocStatus IN ('CO','CL')
|
AND i.DocStatus IN ('CO','CL')
|
||||||
UNION
|
UNION
|
||||||
SELECT i.AD_Org_ID, i.AD_Client_ID,
|
SELECT i.AD_Org_ID, i.AD_Client_ID,
|
||||||
|
@ -39,8 +38,8 @@ SELECT i.AD_Org_ID, i.AD_Client_ID,
|
||||||
ips.DiscountDate,
|
ips.DiscountDate,
|
||||||
ips.DiscountAmt,
|
ips.DiscountAmt,
|
||||||
ips.DueAmt AS GrandTotal,
|
ips.DueAmt AS GrandTotal,
|
||||||
-- invoicePaid(i.C_Invoice_ID, i.C_Currency_ID, 1) AS PaidAmt,
|
--invoicePaid(i.C_Invoice_ID, i.C_Currency_ID, 1) AS PaidAmt,
|
||||||
-- invoiceOpen(i.C_Invoice_ID, ips.C_InvoicePaySchedule_ID) AS OpenAmt,
|
--invoiceOpen(i.C_Invoice_ID, ips.C_InvoicePaySchedule_ID) AS OpenAmt,
|
||||||
i.C_Currency_ID, i.C_ConversionType_ID,
|
i.C_Currency_ID, i.C_ConversionType_ID,
|
||||||
i.C_PaymentTerm_ID,
|
i.C_PaymentTerm_ID,
|
||||||
i.IsPayScheduleValid, ips.C_InvoicePaySchedule_ID, i.InvoiceCollectionType,
|
i.IsPayScheduleValid, ips.C_InvoicePaySchedule_ID, i.InvoiceCollectionType,
|
||||||
|
@ -50,7 +49,6 @@ FROM RV_C_Invoice i
|
||||||
WHERE -- i.IsPaid='N'
|
WHERE -- i.IsPaid='N'
|
||||||
--invoiceOpen(i.C_Invoice_ID,ips.C_InvoicePaySchedule_ID) <> 0 AND
|
--invoiceOpen(i.C_Invoice_ID,ips.C_InvoicePaySchedule_ID) <> 0 AND
|
||||||
i.IsPayScheduleValid='Y'
|
i.IsPayScheduleValid='Y'
|
||||||
AND i.DocStatus<>'DR'
|
|
||||||
AND i.DocStatus IN ('CO','CL')
|
AND i.DocStatus IN ('CO','CL')
|
||||||
AND ips.IsValid='Y';
|
AND ips.IsValid='Y';
|
||||||
|
|
||||||
|
|
|
@ -1,178 +1,167 @@
|
||||||
DROP VIEW rv_orderdetail;
|
DROP VIEW rv_orderdetail;
|
||||||
|
|
||||||
CREATE OR REPLACE VIEW rv_orderdetail
|
CREATE OR REPLACE VIEW rv_orderdetail AS
|
||||||
AS
|
SELECT l.ad_client_id,
|
||||||
SELECT l.ad_client_id,
|
l.ad_org_id,
|
||||||
l.ad_org_id,
|
l.isactive,
|
||||||
l.isactive,
|
l.created,
|
||||||
l.created,
|
l.createdby,
|
||||||
l.createdby,
|
l.updated,
|
||||||
l.updated,
|
l.updatedby,
|
||||||
l.updatedby,
|
o.c_order_id,
|
||||||
o.c_order_id,
|
o.docstatus,
|
||||||
o.docstatus,
|
o.docaction,
|
||||||
o.docaction,
|
o.c_doctype_id,
|
||||||
o.c_doctype_id,
|
o.isapproved,
|
||||||
o.isapproved,
|
o.iscreditapproved,
|
||||||
o.iscreditapproved,
|
o.salesrep_id,
|
||||||
o.salesrep_id,
|
o.bill_bpartner_id,
|
||||||
o.bill_bpartner_id,
|
o.bill_location_id,
|
||||||
o.bill_location_id,
|
o.bill_user_id,
|
||||||
o.bill_user_id,
|
o.isdropship,
|
||||||
o.isdropship,
|
l.c_bpartner_id,
|
||||||
l.c_bpartner_id,
|
l.c_bpartner_location_id,
|
||||||
l.c_bpartner_location_id,
|
o.ad_user_id,
|
||||||
o.ad_user_id,
|
o.poreference,
|
||||||
o.poreference,
|
o.c_currency_id,
|
||||||
o.c_currency_id,
|
o.issotrx,
|
||||||
o.issotrx,
|
l.c_campaign_id,
|
||||||
l.c_campaign_id,
|
l.c_project_id,
|
||||||
l.c_project_id,
|
l.c_activity_id,
|
||||||
l.c_activity_id,
|
l.c_projectphase_id,
|
||||||
l.c_projectphase_id,
|
l.c_projecttask_id,
|
||||||
l.c_projecttask_id,
|
l.c_orderline_id,
|
||||||
l.c_orderline_id,
|
l.dateordered,
|
||||||
l.dateordered,
|
l.datepromised,
|
||||||
l.datepromised,
|
l.m_product_id,
|
||||||
l.m_product_id,
|
l.m_warehouse_id,
|
||||||
l.m_warehouse_id,
|
l.m_attributesetinstance_id,
|
||||||
l.m_attributesetinstance_id,
|
productattribute(l.m_attributesetinstance_id) AS productattribute,
|
||||||
productattribute(l.m_attributesetinstance_id) AS productattribute,
|
pasi.m_attributeset_id,
|
||||||
pasi.m_attributeset_id,
|
pasi.m_lot_id,
|
||||||
pasi.m_lot_id,
|
pasi.guaranteedate,
|
||||||
pasi.guaranteedate,
|
pasi.lot,
|
||||||
pasi.lot,
|
pasi.serno,
|
||||||
pasi.serno,
|
l.c_uom_id,
|
||||||
l.c_uom_id,
|
l.qtyentered,
|
||||||
l.qtyentered,
|
l.qtyordered,
|
||||||
l.qtyordered,
|
l.qtyreserved,
|
||||||
l.qtyreserved,
|
l.qtydelivered,
|
||||||
l.qtydelivered,
|
l.qtyinvoiced,
|
||||||
l.qtyinvoiced,
|
l.priceactual,
|
||||||
l.priceactual,
|
l.priceentered,
|
||||||
l.priceentered,
|
l.qtyordered - l.qtydelivered AS qtytodeliver,
|
||||||
l.qtyordered - l.qtydelivered AS qtytodeliver,
|
l.qtyordered - l.qtyinvoiced AS qtytoinvoice,
|
||||||
l.qtyordered - l.qtyinvoiced AS qtytoinvoice,
|
(l.qtyordered - l.qtyinvoiced) * l.priceactual AS netamttoinvoice,
|
||||||
( l.qtyordered - l.qtyinvoiced ) * l.priceactual AS netamttoinvoice,
|
l.qtylostsales,
|
||||||
l.qtylostsales,
|
l.qtylostsales * l.priceactual AS amtlostsales,
|
||||||
l.qtylostsales * l.priceactual AS amtlostsales,
|
CASE WHEN l.pricelist = 0 THEN 0 ELSE currencyRound((l.pricelist - l.priceactual) / l.pricelist * 100,o.C_Currency_ID,'N') END AS discount,
|
||||||
CASE
|
CASE WHEN l.pricelimit = 0 THEN 0 ELSE currencyRound((l.priceactual - l.pricelimit) / l.pricelimit * 100,o.C_Currency_ID,'N') END AS margin,
|
||||||
WHEN l.pricelist = 0 THEN 0
|
CASE WHEN l.pricelimit = 0 THEN 0 ELSE (l.priceactual - l.pricelimit) * l.qtydelivered END AS marginamt,
|
||||||
ELSE round(( l.pricelist - l.priceactual ) / l.pricelist * 100, 2)
|
o.ad_org_id AS c_order_ad_org_id,
|
||||||
END AS discount,
|
o.ad_orgtrx_id AS c_order_ad_orgtrx_id,
|
||||||
CASE
|
o.amountrefunded,
|
||||||
WHEN l.pricelimit = 0 THEN 0
|
o.amounttendered,
|
||||||
ELSE round(( l.priceactual - l.pricelimit ) / l.pricelimit * 100, 2)
|
o.c_activity_id AS c_order_c_activity_id,
|
||||||
END AS margin,
|
o.c_bpartner_id AS c_order_c_bpartner_id,
|
||||||
CASE
|
o.c_bpartner_location_id AS c_order_c_bpartner_loc_id,
|
||||||
WHEN l.pricelimit = 0 THEN 0
|
o.c_campaign_id AS c_order_c_compaign_id,
|
||||||
ELSE ( l.priceactual - l.pricelimit ) * l.qtydelivered
|
o.c_cashline_id,
|
||||||
END AS marginamt,
|
o.c_cashplanline_id,
|
||||||
o.ad_org_id AS c_order_ad_org_id,
|
o.c_charge_id AS c_order_c_charge_id,
|
||||||
o.ad_orgtrx_id AS c_order_ad_orgtrx_id,
|
o.c_conversiontype_id,
|
||||||
o.amountrefunded,
|
o.c_doctypetarget_id,
|
||||||
o.amounttendered,
|
o.chargeamt,
|
||||||
o.c_activity_id AS c_order_c_activity_id,
|
o.copyfrom,
|
||||||
o.c_bpartner_id AS c_order_c_bpartner_id,
|
o.c_payment_id,
|
||||||
o.c_bpartner_location_id AS c_order_c_bpartner_loc_id,
|
o.c_paymentterm_id,
|
||||||
o.c_campaign_id AS c_order_c_compaign_id,
|
o.c_pos_id,
|
||||||
o.c_cashline_id,
|
o.c_project_id AS c_order_c_project_id,
|
||||||
o.c_cashplanline_id,
|
o.created AS c_order_created,
|
||||||
o.c_charge_id AS c_order_c_charge_id,
|
o.createdby AS c_order_createdby,
|
||||||
o.c_conversiontype_id,
|
o.dateacct,
|
||||||
o.c_doctypetarget_id,
|
o.dateordered AS c_order_dateordered,
|
||||||
o.chargeamt,
|
o.dateprinted,
|
||||||
o.copyfrom,
|
o.datepromised AS c_order_datepromised,
|
||||||
o.c_payment_id,
|
o.deliveryrule,
|
||||||
o.c_paymentterm_id,
|
o.deliveryviarule,
|
||||||
o.c_pos_id,
|
o.description AS c_order_description,
|
||||||
o.c_project_id AS c_order_c_project_id,
|
o.documentno,
|
||||||
o.created AS c_order_created,
|
o.dropship_bpartner_id,
|
||||||
o.createdby AS c_order_createdby,
|
o.dropship_location_id,
|
||||||
o.dateacct,
|
o.dropship_user_id,
|
||||||
o.dateordered AS c_order_dateordered,
|
o.freightamt AS c_order_freightamt,
|
||||||
o.dateprinted,
|
o.freightcostrule,
|
||||||
o.datepromised AS c_order_datepromised,
|
o.grandtotal,
|
||||||
o.deliveryrule,
|
o.invoicerule,
|
||||||
o.deliveryviarule,
|
o.isactive AS c_order_isactive,
|
||||||
o.description AS c_order_description,
|
o.isdelivered,
|
||||||
o.documentno,
|
o.isdiscountprinted,
|
||||||
o.dropship_bpartner_id,
|
o.isinvoiced,
|
||||||
o.dropship_location_id,
|
o.ispayschedulevalid,
|
||||||
o.dropship_user_id,
|
o.isprinted,
|
||||||
o.freightamt AS c_order_freightamt,
|
o.isselected,
|
||||||
o.freightcostrule,
|
o.isselfservice,
|
||||||
o.grandtotal,
|
o.istaxincluded,
|
||||||
o.invoicerule,
|
o.istransferred,
|
||||||
o.isactive AS c_order_isactive,
|
o.link_order_id,
|
||||||
o.isdelivered,
|
o.m_freightcategory_id,
|
||||||
o.isdiscountprinted,
|
o.m_pricelist_id,
|
||||||
o.isinvoiced,
|
o.m_shipper_id AS c_order_m_shipper_id,
|
||||||
o.ispayschedulevalid,
|
o.m_warehouse_id AS c_order_m_warehouse_id,
|
||||||
o.isprinted,
|
o.ordertype,
|
||||||
o.isselected,
|
o.pay_bpartner_id,
|
||||||
o.isselfservice,
|
o.pay_location_id,
|
||||||
o.istaxincluded,
|
o.paymentrule,
|
||||||
o.istransferred,
|
o.posted,
|
||||||
o.link_order_id,
|
o.priorityrule,
|
||||||
o.m_freightcategory_id,
|
o.processed AS c_order_processed,
|
||||||
o.m_pricelist_id,
|
o.processedon,
|
||||||
o.m_shipper_id AS c_order_m_shipper_id,
|
o.promotioncode,
|
||||||
o.m_warehouse_id AS c_order_m_warehouse_id,
|
o.ref_order_id,
|
||||||
o.ordertype,
|
o.sendemail,
|
||||||
o.pay_bpartner_id,
|
o.totallines,
|
||||||
o.pay_location_id,
|
o.updated AS c_order_updated,
|
||||||
o.paymentrule,
|
o.updatedby AS c_order_updatedby,
|
||||||
o.posted,
|
o.user1_id AS c_order_user1_id,
|
||||||
o.priorityrule,
|
o.user2_id AS c_order_user2_id,
|
||||||
o.processed AS c_order_processed,
|
o.volume,
|
||||||
o.processedon,
|
o.weight,
|
||||||
o.promotioncode,
|
l.ad_orgtrx_id AS c_orderline_ad_orgtrx_id,
|
||||||
o.ref_order_id,
|
l.c_charge_id AS c_orderline_c_charge_id,
|
||||||
o.sendemail,
|
l.c_currency_id AS c_orderline_c_currency_id,
|
||||||
o.totallines,
|
l.c_tax_id,
|
||||||
o.updated AS c_order_updated,
|
l.datedelivered,
|
||||||
o.updatedby AS c_order_updatedby,
|
l.dateinvoiced,
|
||||||
o.user1_id AS c_order_user1_id,
|
l.description AS c_orderline_description,
|
||||||
o.user2_id AS c_order_user2_id,
|
l.discount AS c_orderline_discount,
|
||||||
o.volume,
|
l.freightamt AS c_orderline_freightamt,
|
||||||
o.weight,
|
l.isdescription,
|
||||||
l.ad_orgtrx_id AS c_orderline_ad_orgtrx_id,
|
l.line,
|
||||||
l.c_charge_id AS c_orderline_c_charge_id,
|
l.linenetamt,
|
||||||
l.c_currency_id AS c_orderline_c_currency_id,
|
l.link_orderline_id,
|
||||||
l.c_tax_id,
|
l.m_promotion_id,
|
||||||
l.datedelivered,
|
l.m_shipper_id AS c_orderline_m_shipper_id,
|
||||||
l.dateinvoiced,
|
l.pricecost,
|
||||||
l.description AS c_orderline_description,
|
l.pricelimit,
|
||||||
l.discount AS c_orderline_discount,
|
l.pricelist,
|
||||||
l.freightamt AS c_orderline_freightamt,
|
l.processed AS c_orderline_processed,
|
||||||
l.isdescription,
|
l.ref_orderline_id,
|
||||||
l.line,
|
l.rramt,
|
||||||
l.linenetamt,
|
l.rrstartdate,
|
||||||
l.link_orderline_id,
|
l.s_resourceassignment_id,
|
||||||
l.m_promotion_id,
|
l.user1_id AS c_orderline_user1_id,
|
||||||
l.m_shipper_id AS c_orderline_m_shipper_id,
|
l.user2_id AS c_orderline_user2_id,
|
||||||
l.pricecost,
|
pasi.ad_org_id AS m_asi_ad_org_id,
|
||||||
l.pricelimit,
|
pasi.created AS m_asi_created,
|
||||||
l.pricelist,
|
pasi.createdby AS m_asi_createdby,
|
||||||
l.processed AS c_orderline_processed,
|
pasi.description AS m_asi_description,
|
||||||
l.ref_orderline_id,
|
pasi.isactive AS m_asi_isactive,
|
||||||
l.rramt,
|
pasi.updated AS m_asi_updated,
|
||||||
l.rrstartdate,
|
pasi.updatedby AS m_asi_updatedby
|
||||||
l.s_resourceassignment_id,
|
FROM c_order o
|
||||||
l.user1_id AS c_orderline_user1_id,
|
JOIN c_orderline l
|
||||||
l.user2_id AS c_orderline_user2_id,
|
ON o.c_order_id = l.c_order_id
|
||||||
pasi.ad_org_id AS m_asi_ad_org_id,
|
LEFT JOIN m_attributesetinstance pasi
|
||||||
pasi.created AS m_asi_created,
|
ON l.m_attributesetinstance_id = pasi.m_attributesetinstance_id
|
||||||
pasi.createdby AS m_asi_createdby,
|
|
||||||
pasi.description AS m_asi_description,
|
|
||||||
pasi.isactive AS m_asi_isactive,
|
|
||||||
pasi.updated AS m_asi_updated,
|
|
||||||
pasi.updatedby AS m_asi_updatedby
|
|
||||||
FROM c_order o
|
|
||||||
JOIN c_orderline l
|
|
||||||
ON o.c_order_id = l.c_order_id
|
|
||||||
LEFT JOIN m_attributesetinstance pasi
|
|
||||||
ON l.m_attributesetinstance_id = pasi.m_attributesetinstance_id
|
|
||||||
;
|
;
|
||||||
|
|
||||||
|
|
|
@ -44,6 +44,8 @@ AS
|
||||||
$BODY$
|
$BODY$
|
||||||
DECLARE
|
DECLARE
|
||||||
v_Currency_ID numeric(10);
|
v_Currency_ID numeric(10);
|
||||||
|
v_Precision NUMERIC := 0;
|
||||||
|
v_Min NUMERIC := 0;
|
||||||
v_TotalOpenAmt numeric := 0;
|
v_TotalOpenAmt numeric := 0;
|
||||||
v_PaidAmt numeric := 0;
|
v_PaidAmt numeric := 0;
|
||||||
v_Remaining numeric := 0;
|
v_Remaining numeric := 0;
|
||||||
|
@ -67,6 +69,13 @@ BEGIN
|
||||||
END;
|
END;
|
||||||
-- DBMS_OUTPUT.PUT_LINE('== C_Invoice_ID=' || p_C_Invoice_ID || ', Total=' || v_TotalOpenAmt || ', AP=' || v_MultiplierAP || ', CM=' || v_MultiplierCM);
|
-- 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
|
-- Calculate Allocated Amount
|
||||||
FOR allocationline IN
|
FOR allocationline IN
|
||||||
SELECT a.AD_Client_ID, a.AD_Org_ID,
|
SELECT a.AD_Client_ID, a.AD_Org_ID,
|
||||||
|
@ -112,14 +121,15 @@ BEGIN
|
||||||
END IF;
|
END IF;
|
||||||
-- DBMS_OUTPUT.PUT_LINE('== Total=' || v_TotalOpenAmt);
|
-- DBMS_OUTPUT.PUT_LINE('== Total=' || v_TotalOpenAmt);
|
||||||
|
|
||||||
-- Ignore Rounding
|
-- 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;
|
v_TotalOpenAmt := 0;
|
||||||
END IF;
|
END IF;
|
||||||
|
|
||||||
-- Round to penny
|
-- Round to currency precision
|
||||||
v_TotalOpenAmt := ROUND(COALESCE(v_TotalOpenAmt,0), 2);
|
v_TotalOpenAmt := ROUND(COALESCE(v_TotalOpenAmt,0), v_Precision);
|
||||||
RETURN v_TotalOpenAmt;
|
|
||||||
|
RETURN v_TotalOpenAmt;
|
||||||
END;
|
END;
|
||||||
$BODY$
|
$BODY$
|
||||||
LANGUAGE 'plpgsql' ;
|
LANGUAGE 'plpgsql' ;
|
||||||
|
|
|
@ -33,11 +33,20 @@ RETURNS numeric AS $body$
|
||||||
*
|
*
|
||||||
************************************************************************/
|
************************************************************************/
|
||||||
DECLARE
|
DECLARE
|
||||||
|
v_Precision NUMERIC := 0;
|
||||||
|
v_Min NUMERIC := 0;
|
||||||
v_MultiplierAP NUMERIC := 1;
|
v_MultiplierAP NUMERIC := 1;
|
||||||
v_PaymentAmt NUMERIC := 0;
|
v_PaymentAmt NUMERIC := 0;
|
||||||
ar RECORD;
|
ar RECORD;
|
||||||
|
|
||||||
BEGIN
|
BEGIN
|
||||||
|
SELECT StdPrecision
|
||||||
|
INTO v_Precision
|
||||||
|
FROM C_Currency
|
||||||
|
WHERE C_Currency_ID = p_C_Currency_ID;
|
||||||
|
|
||||||
|
SELECT 1/10^v_Precision INTO v_Min;
|
||||||
|
|
||||||
-- Default
|
-- Default
|
||||||
IF (p_MultiplierAP IS NOT NULL) THEN
|
IF (p_MultiplierAP IS NOT NULL) THEN
|
||||||
v_MultiplierAP := p_MultiplierAP;
|
v_MultiplierAP := p_MultiplierAP;
|
||||||
|
@ -56,8 +65,16 @@ BEGIN
|
||||||
+ currencyConvert(ar.Amount + ar.DisCountAmt + ar.WriteOffAmt,
|
+ currencyConvert(ar.Amount + ar.DisCountAmt + ar.WriteOffAmt,
|
||||||
ar.C_Currency_ID, p_C_Currency_ID, ar.DateTrx, null, ar.AD_Client_ID, ar.AD_Org_ID);
|
ar.C_Currency_ID, p_C_Currency_ID, ar.DateTrx, null, ar.AD_Client_ID, ar.AD_Org_ID);
|
||||||
END LOOP;
|
END LOOP;
|
||||||
--
|
|
||||||
RETURN ROUND(COALESCE(v_PaymentAmt,0), 2) * v_MultiplierAP;
|
-- Ignore Rounding
|
||||||
|
IF (v_PaymentAmt > -v_Min AND v_PaymentAmt < v_Min) THEN
|
||||||
|
v_PaymentAmt := 0;
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
-- Round to currency precision
|
||||||
|
v_PaymentAmt := ROUND(COALESCE(v_PaymentAmt,0), v_Precision);
|
||||||
|
|
||||||
|
RETURN v_PaymentAmt * v_MultiplierAP;
|
||||||
END;
|
END;
|
||||||
|
|
||||||
$body$ LANGUAGE plpgsql;
|
$body$ LANGUAGE plpgsql;
|
||||||
|
|
|
@ -45,10 +45,19 @@ RETURNS numeric
|
||||||
AS
|
AS
|
||||||
$BODY$
|
$BODY$
|
||||||
DECLARE
|
DECLARE
|
||||||
|
v_Precision NUMERIC := 0;
|
||||||
|
v_Min NUMERIC := 0;
|
||||||
v_MultiplierAP numeric := 1;
|
v_MultiplierAP numeric := 1;
|
||||||
v_PaymentAmt numeric := 0;
|
v_PaymentAmt numeric := 0;
|
||||||
allocation record;
|
allocation record;
|
||||||
BEGIN
|
BEGIN
|
||||||
|
SELECT StdPrecision
|
||||||
|
INTO v_Precision
|
||||||
|
FROM C_Currency
|
||||||
|
WHERE C_Currency_ID = p_C_Currency_ID;
|
||||||
|
|
||||||
|
SELECT 1/10^v_Precision INTO v_Min;
|
||||||
|
|
||||||
-- Default
|
-- Default
|
||||||
IF (p_MultiplierAP IS NOT NULL) THEN
|
IF (p_MultiplierAP IS NOT NULL) THEN
|
||||||
v_MultiplierAP := p_MultiplierAP;
|
v_MultiplierAP := p_MultiplierAP;
|
||||||
|
@ -64,8 +73,16 @@ BEGIN
|
||||||
+ Currencyconvert(allocation.Amount + allocation.DisCountAmt + allocation.WriteOffAmt,
|
+ 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);
|
allocation.C_Currency_ID, p_C_Currency_ID, allocation.DateTrx, NULL, allocation.AD_Client_ID, allocation.AD_Org_ID);
|
||||||
END LOOP;
|
END LOOP;
|
||||||
--
|
|
||||||
RETURN ROUND(COALESCE(v_PaymentAmt,0), 2) * v_MultiplierAP;
|
-- Ignore Rounding
|
||||||
|
IF (v_PaymentAmt > -v_Min AND v_PaymentAmt < v_Min) THEN
|
||||||
|
v_PaymentAmt := 0;
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
-- Round to currency precision
|
||||||
|
v_PaymentAmt := ROUND(COALESCE(v_PaymentAmt,0), v_Precision);
|
||||||
|
|
||||||
|
RETURN v_PaymentAmt * v_MultiplierAP;
|
||||||
END;
|
END;
|
||||||
$BODY$
|
$BODY$
|
||||||
LANGUAGE 'plpgsql' ;
|
LANGUAGE 'plpgsql' ;
|
||||||
|
|
|
@ -25,6 +25,8 @@ RETURNS NUMERIC AS $body$
|
||||||
************************************************************************/
|
************************************************************************/
|
||||||
|
|
||||||
DECLARE
|
DECLARE
|
||||||
|
v_Precision NUMERIC := 0;
|
||||||
|
v_Min NUMERIC := 0;
|
||||||
Discount NUMERIC := 0;
|
Discount NUMERIC := 0;
|
||||||
Discount1Date timestamp with time zone;
|
Discount1Date timestamp with time zone;
|
||||||
Discount2Date timestamp with time zone;
|
Discount2Date timestamp with time zone;
|
||||||
|
@ -32,6 +34,13 @@ DECLARE
|
||||||
Add2Date NUMERIC := 0;
|
Add2Date NUMERIC := 0;
|
||||||
p RECORD;
|
p RECORD;
|
||||||
BEGIN
|
BEGIN
|
||||||
|
SELECT StdPrecision
|
||||||
|
INTO v_Precision
|
||||||
|
FROM C_Currency
|
||||||
|
WHERE C_Currency_ID = Currency_ID;
|
||||||
|
|
||||||
|
SELECT 1/10^v_Precision INTO v_Min;
|
||||||
|
|
||||||
-- No Data - No Discount
|
-- No Data - No Discount
|
||||||
IF (Amount IS NULL OR PaymentTerm_ID IS NULL OR DocDate IS NULL) THEN
|
IF (Amount IS NULL OR PaymentTerm_ID IS NULL OR DocDate IS NULL) THEN
|
||||||
RETURN 0;
|
RETURN 0;
|
||||||
|
@ -59,8 +68,16 @@ BEGIN
|
||||||
Discount := Amount * p.Discount2 / 100;
|
Discount := Amount * p.Discount2 / 100;
|
||||||
END IF;
|
END IF;
|
||||||
END LOOP;
|
END LOOP;
|
||||||
--
|
|
||||||
RETURN ROUND(COALESCE(Discount,0), 2); -- fixed rounding
|
-- Ignore Rounding
|
||||||
|
IF (Discount > -v_Min AND Discount < v_Min) THEN
|
||||||
|
Discount := 0;
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
-- Round to currency precision
|
||||||
|
Discount := ROUND(COALESCE(Discount,0), v_Precision);
|
||||||
|
|
||||||
|
RETURN Discount;
|
||||||
END;
|
END;
|
||||||
|
|
||||||
$body$ LANGUAGE plpgsql;
|
$body$ LANGUAGE plpgsql;
|
||||||
|
|
|
@ -28,10 +28,19 @@ RETURNS NUMERIC AS $body$
|
||||||
|
|
||||||
************************************************************************/
|
************************************************************************/
|
||||||
DECLARE
|
DECLARE
|
||||||
|
v_Precision NUMERIC := 0;
|
||||||
|
v_Min NUMERIC := 0;
|
||||||
v_AllocatedAmt NUMERIC := 0;
|
v_AllocatedAmt NUMERIC := 0;
|
||||||
v_PayAmt NUMERIC;
|
v_PayAmt NUMERIC;
|
||||||
r RECORD;
|
r RECORD;
|
||||||
BEGIN
|
BEGIN
|
||||||
|
SELECT StdPrecision
|
||||||
|
INTO v_Precision
|
||||||
|
FROM C_Currency
|
||||||
|
WHERE C_Currency_ID = p_C_Currency_ID;
|
||||||
|
|
||||||
|
SELECT 1/10^v_Precision INTO v_Min;
|
||||||
|
|
||||||
-- Charge - nothing available
|
-- Charge - nothing available
|
||||||
SELECT
|
SELECT
|
||||||
INTO v_PayAmt MAX(PayAmt)
|
INTO v_PayAmt MAX(PayAmt)
|
||||||
|
@ -53,8 +62,15 @@ BEGIN
|
||||||
v_AllocatedAmt := v_AllocatedAmt
|
v_AllocatedAmt := v_AllocatedAmt
|
||||||
+ currencyConvert(r.Amount, r.C_Currency_ID, p_C_Currency_ID, r.DateTrx, null, r.AD_Client_ID, r.AD_Org_ID);
|
+ currencyConvert(r.Amount, r.C_Currency_ID, p_C_Currency_ID, r.DateTrx, null, r.AD_Client_ID, r.AD_Org_ID);
|
||||||
END LOOP;
|
END LOOP;
|
||||||
-- Round to penny
|
|
||||||
v_AllocatedAmt := ROUND(COALESCE(v_AllocatedAmt,0), 2);
|
-- Ignore Rounding
|
||||||
|
IF (v_AllocatedAmt > -v_Min AND v_AllocatedAmt < v_Min) THEN
|
||||||
|
v_AllocatedAmt := 0;
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
-- Round to currency precision
|
||||||
|
v_AllocatedAmt := ROUND(COALESCE(v_AllocatedAmt,0), v_Precision);
|
||||||
|
|
||||||
RETURN v_AllocatedAmt;
|
RETURN v_AllocatedAmt;
|
||||||
END;
|
END;
|
||||||
|
|
||||||
|
|
|
@ -19,6 +19,8 @@ RETURNS NUMERIC AS $body$
|
||||||
************************************************************************/
|
************************************************************************/
|
||||||
DECLARE
|
DECLARE
|
||||||
v_Currency_ID NUMERIC(10);
|
v_Currency_ID NUMERIC(10);
|
||||||
|
v_Precision NUMERIC := 0;
|
||||||
|
v_Min NUMERIC := 0;
|
||||||
v_AvailableAmt NUMERIC := 0;
|
v_AvailableAmt NUMERIC := 0;
|
||||||
v_IsReceipt C_Payment.IsReceipt%TYPE;
|
v_IsReceipt C_Payment.IsReceipt%TYPE;
|
||||||
v_Amt NUMERIC := 0;
|
v_Amt NUMERIC := 0;
|
||||||
|
@ -41,6 +43,13 @@ BEGIN
|
||||||
WHERE C_Payment_ID = p_C_Payment_ID;
|
WHERE C_Payment_ID = p_C_Payment_ID;
|
||||||
-- DBMS_OUTPUT.PUT_LINE('== C_Payment_ID=' || p_C_Payment_ID || ', PayAmt=' || v_AvailableAmt || ', Receipt=' || v_IsReceipt);
|
-- DBMS_OUTPUT.PUT_LINE('== C_Payment_ID=' || p_C_Payment_ID || ', PayAmt=' || v_AvailableAmt || ', Receipt=' || v_IsReceipt);
|
||||||
|
|
||||||
|
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
|
-- Calculate Allocated Amount
|
||||||
FOR r IN
|
FOR r IN
|
||||||
SELECT a.AD_Client_ID, a.AD_Org_ID, al.Amount, a.C_Currency_ID, a.DateTrx
|
SELECT a.AD_Client_ID, a.AD_Org_ID, al.Amount, a.C_Currency_ID, a.DateTrx
|
||||||
|
@ -53,12 +62,15 @@ BEGIN
|
||||||
v_AvailableAmt := v_AvailableAmt - v_Amt;
|
v_AvailableAmt := v_AvailableAmt - v_Amt;
|
||||||
-- DBMS_OUTPUT.PUT_LINE(' Allocation=' || a.Amount || ' - Available=' || v_AvailableAmt);
|
-- DBMS_OUTPUT.PUT_LINE(' Allocation=' || a.Amount || ' - Available=' || v_AvailableAmt);
|
||||||
END LOOP;
|
END LOOP;
|
||||||
|
|
||||||
-- Ignore Rounding
|
-- Ignore Rounding
|
||||||
IF (v_AvailableAmt BETWEEN -0.00999 AND 0.00999) THEN
|
IF (v_AvailableAmt > -v_Min AND v_AvailableAmt < v_Min) THEN
|
||||||
v_AvailableAmt := 0;
|
v_AvailableAmt := 0;
|
||||||
END IF;
|
END IF;
|
||||||
-- Round to penny
|
|
||||||
v_AvailableAmt := ROUND(COALESCE(v_AvailableAmt,0), 2);
|
-- Round to currency precision
|
||||||
|
v_AvailableAmt := ROUND(COALESCE(v_AvailableAmt,0), v_Precision);
|
||||||
|
|
||||||
RETURN v_AvailableAmt;
|
RETURN v_AvailableAmt;
|
||||||
END;
|
END;
|
||||||
|
|
||||||
|
|
|
@ -11,11 +11,11 @@ SELECT il.AD_Client_ID, il.AD_Org_ID,
|
||||||
i.C_BPartner_ID, il.M_Product_ID,
|
i.C_BPartner_ID, il.M_Product_ID,
|
||||||
i.DocumentNo, i.DateInvoiced, i.DateAcct,
|
i.DocumentNo, i.DateInvoiced, i.DateAcct,
|
||||||
i.IsSOTrx, i.DocStatus,
|
i.IsSOTrx, i.DocStatus,
|
||||||
ROUND(i.Multiplier*LineNetAmt, 2) AS LineNetAmt,
|
currencyRound(i.Multiplier*LineNetAmt,i.C_Currency_ID,'N') AS LineNetAmt,
|
||||||
ROUND(i.Multiplier*PriceList*QtyInvoiced, 2) AS LineListAmt,
|
currencyRound(i.Multiplier*PriceList*QtyInvoiced,i.C_Currency_ID,'N') AS LineListAmt,
|
||||||
CASE WHEN COALESCE(il.PriceLimit, 0)=0 THEN ROUND(i.Multiplier*LineNetAmt,2) ELSE ROUND(i.Multiplier*il.PriceLimit*il.QtyInvoiced,2) END AS LineLimitAmt,
|
CASE WHEN COALESCE(il.PriceLimit, 0)=0 THEN currencyRound(i.Multiplier*LineNetAmt,i.C_Currency_ID,'N') ELSE currencyRound(i.Multiplier*il.PriceLimit*il.QtyInvoiced,i.C_Currency_ID,'N') END AS LineLimitAmt,
|
||||||
ROUND(i.Multiplier*il.PriceList*il.QtyInvoiced-il.LineNetAmt,2) AS LineDiscountAmt,
|
currencyRound(i.Multiplier*il.PriceList*il.QtyInvoiced-il.LineNetAmt,i.C_Currency_ID,'N') AS LineDiscountAmt,
|
||||||
CASE WHEN COALESCE(il.PriceLimit,0)=0 THEN 0 ELSE ROUND(i.Multiplier*il.LineNetAmt-il.PriceLimit*il.QtyInvoiced,2) END AS LineOverLimitAmt,
|
CASE WHEN COALESCE(il.PriceLimit,0)=0 THEN 0 ELSE currencyRound(i.Multiplier*il.LineNetAmt-il.PriceLimit*il.QtyInvoiced,i.C_Currency_ID,'N') END AS LineOverLimitAmt,
|
||||||
il.QtyInvoiced, il.QtyEntered,
|
il.QtyInvoiced, il.QtyEntered,
|
||||||
il.Line, il.C_OrderLine_ID, il.C_UOM_ID,
|
il.Line, il.C_OrderLine_ID, il.C_UOM_ID,
|
||||||
il.C_Campaign_ID, il.C_Project_ID, il.C_Activity_ID, il.C_ProjectPhase_ID, il.C_ProjectTask_ID
|
il.C_Campaign_ID, il.C_Project_ID, il.C_Activity_ID, il.C_ProjectPhase_ID, il.C_ProjectTask_ID
|
||||||
|
|
|
@ -13,7 +13,7 @@ SELECT s.ad_client_id,
|
||||||
sum(ms.qtyonhand - ms.qtyreserved) AS qtyavailable,
|
sum(ms.qtyonhand - ms.qtyreserved) AS qtyavailable,
|
||||||
sum(ms.qtyonhand) AS qtyonhand,
|
sum(ms.qtyonhand) AS qtyonhand,
|
||||||
sum(ms.qtyreserved) AS qtyreserved,
|
sum(ms.qtyreserved) AS qtyreserved,
|
||||||
ROUND(MAX(mpr.pricestd),0) AS pricestd,
|
currencyRound(MAX(mpr.pricestd),mpl.C_Currency_ID,'N') AS pricestd,
|
||||||
mpr.m_pricelist_version_id,
|
mpr.m_pricelist_version_id,
|
||||||
mw.m_warehouse_id,
|
mw.m_warehouse_id,
|
||||||
org.name AS orgname
|
org.name AS orgname
|
||||||
|
@ -23,6 +23,8 @@ SELECT s.ad_client_id,
|
||||||
JOIN m_locator ml ON ms.m_locator_id = ml.m_locator_id
|
JOIN m_locator ml ON ms.m_locator_id = ml.m_locator_id
|
||||||
JOIN m_warehouse mw ON ml.m_warehouse_id = mw.m_warehouse_id
|
JOIN m_warehouse mw ON ml.m_warehouse_id = mw.m_warehouse_id
|
||||||
JOIN m_productprice mpr ON ms.m_product_id = mpr.m_product_id
|
JOIN m_productprice mpr ON ms.m_product_id = mpr.m_product_id
|
||||||
|
JOIN m_pricelist_version mplv ON mplv.m_pricelist_version_id = mpr.m_pricelist_version_id
|
||||||
|
JOIN m_pricelist mpl ON mplv.m_pricelist_id = mpl.m_pricelist_id
|
||||||
JOIN ad_org org ON org.ad_org_id = mw.ad_org_id
|
JOIN ad_org org ON org.ad_org_id = mw.ad_org_id
|
||||||
GROUP BY s.ad_client_id,
|
GROUP BY s.ad_client_id,
|
||||||
s.ad_org_id,
|
s.ad_org_id,
|
||||||
|
@ -36,7 +38,8 @@ SELECT s.ad_client_id,
|
||||||
mw.m_warehouse_id,
|
mw.m_warehouse_id,
|
||||||
mpr.m_pricelist_version_id,
|
mpr.m_pricelist_version_id,
|
||||||
org.name,
|
org.name,
|
||||||
mp.name
|
mp.name,
|
||||||
|
mpl.C_Currency_ID
|
||||||
UNION
|
UNION
|
||||||
SELECT r.ad_client_id,
|
SELECT r.ad_client_id,
|
||||||
r.ad_org_id,
|
r.ad_org_id,
|
||||||
|
@ -52,7 +55,7 @@ SELECT s.ad_client_id,
|
||||||
sum(ms.qtyonhand - ms.qtyreserved) AS qtyavailable,
|
sum(ms.qtyonhand - ms.qtyreserved) AS qtyavailable,
|
||||||
sum(ms.qtyonhand) AS qtyonhand,
|
sum(ms.qtyonhand) AS qtyonhand,
|
||||||
sum(ms.qtyreserved) AS qtyreserved,
|
sum(ms.qtyreserved) AS qtyreserved,
|
||||||
ROUND(MAX(mpr.pricestd),0) AS pricestd,
|
currencyRound(MAX(mpr.pricestd),mpl.C_Currency_ID,'N') AS pricestd,
|
||||||
mpr.m_pricelist_version_id,
|
mpr.m_pricelist_version_id,
|
||||||
mw.m_warehouse_id,
|
mw.m_warehouse_id,
|
||||||
org.name AS orgname
|
org.name AS orgname
|
||||||
|
@ -62,6 +65,8 @@ SELECT s.ad_client_id,
|
||||||
JOIN m_locator ml ON ms.m_locator_id = ml.m_locator_id
|
JOIN m_locator ml ON ms.m_locator_id = ml.m_locator_id
|
||||||
JOIN m_warehouse mw ON ml.m_warehouse_id = mw.m_warehouse_id
|
JOIN m_warehouse mw ON ml.m_warehouse_id = mw.m_warehouse_id
|
||||||
JOIN m_productprice mpr ON ms.m_product_id = mpr.m_product_id
|
JOIN m_productprice mpr ON ms.m_product_id = mpr.m_product_id
|
||||||
|
JOIN m_pricelist_version mplv ON mplv.m_pricelist_version_id = mpr.m_pricelist_version_id
|
||||||
|
JOIN m_pricelist mpl ON mplv.m_pricelist_id = mpl.m_pricelist_id
|
||||||
JOIN ad_org org ON org.ad_org_id = mw.ad_org_id
|
JOIN ad_org org ON org.ad_org_id = mw.ad_org_id
|
||||||
GROUP BY r.ad_client_id,
|
GROUP BY r.ad_client_id,
|
||||||
r.ad_org_id,
|
r.ad_org_id,
|
||||||
|
@ -75,4 +80,5 @@ SELECT s.ad_client_id,
|
||||||
mw.m_warehouse_id,
|
mw.m_warehouse_id,
|
||||||
mpr.m_pricelist_version_id,
|
mpr.m_pricelist_version_id,
|
||||||
org.name,
|
org.name,
|
||||||
mp.name;
|
mp.name,
|
||||||
|
mpl.C_Currency_ID;
|
|
@ -37,15 +37,15 @@ SELECT il.ad_client_id,
|
||||||
il.priceactual,
|
il.priceactual,
|
||||||
il.pricelimit,
|
il.pricelimit,
|
||||||
il.priceentered,
|
il.priceentered,
|
||||||
CASE WHEN il.pricelist = 0 THEN 0 ELSE round((il.pricelist - il.priceactual) / il.pricelist * 100, 2) END AS discount,
|
CASE WHEN il.pricelist = 0 THEN 0 ELSE currencyRound((il.pricelist - il.priceactual) / il.pricelist * 100,i.C_Currency_ID,'N') END AS discount,
|
||||||
CASE WHEN il.pricelimit = 0 THEN 0 ELSE round((il.priceactual - il.pricelimit) / il.pricelimit * 100, 2) END AS margin,
|
CASE WHEN il.pricelimit = 0 THEN 0 ELSE currencyRound((il.priceactual - il.pricelimit) / il.pricelimit * 100,i.C_Currency_ID,'N') END AS margin,
|
||||||
CASE WHEN il.pricelimit = 0 THEN 0 ELSE (il.priceactual - il.pricelimit) * il.qtyinvoiced END AS marginamt,
|
CASE WHEN il.pricelimit = 0 THEN 0 ELSE (il.priceactual - il.pricelimit) * il.qtyinvoiced END AS marginamt,
|
||||||
round(i.multiplier * il.linenetamt, 2) AS linenetamt,
|
currencyRound(i.multiplier * il.linenetamt,i.C_Currency_ID,'N') AS linenetamt,
|
||||||
round(i.multiplier * il.pricelist * il.qtyinvoiced, 2) AS linelistamt,
|
currencyRound(i.multiplier * il.pricelist * il.qtyinvoiced,i.C_Currency_ID,'N') AS linelistamt,
|
||||||
CASE WHEN COALESCE(il.pricelimit, 0) = 0 THEN round(i.multiplier * il.linenetamt, 2) ELSE round(i.multiplier * il.pricelimit * il.qtyinvoiced, 2) END
|
CASE WHEN COALESCE(il.pricelimit, 0) = 0 THEN currencyRound(i.multiplier * il.linenetamt,i.C_Currency_ID,'N') ELSE currencyRound(i.multiplier * il.pricelimit * il.qtyinvoiced,i.C_Currency_ID,'N') END
|
||||||
AS linelimitamt,
|
AS linelimitamt,
|
||||||
round(i.multiplier * il.pricelist * il.qtyinvoiced - il.linenetamt, 2) AS linediscountamt,
|
currencyRound(i.multiplier * il.pricelist * il.qtyinvoiced - il.linenetamt,i.C_Currency_ID,'N') AS linediscountamt,
|
||||||
CASE WHEN COALESCE(il.pricelimit, 0) = 0 THEN 0 ELSE round(i.multiplier * il.linenetamt - il.pricelimit * il.qtyinvoiced, 2) END AS
|
CASE WHEN COALESCE(il.pricelimit, 0) = 0 THEN 0 ELSE currencyRound(i.multiplier * il.linenetamt - il.pricelimit * il.qtyinvoiced,i.C_Currency_ID,'N') END AS
|
||||||
lineoverlimitamt,
|
lineoverlimitamt,
|
||||||
il.ad_orgtrx_id,
|
il.ad_orgtrx_id,
|
||||||
il.a_processed,
|
il.a_processed,
|
||||||
|
|
|
@ -11,14 +11,15 @@ SELECT il.AD_Client_ID, il.AD_Org_ID,
|
||||||
SUM(LineLimitAmt) AS LineLimitAmt,
|
SUM(LineLimitAmt) AS LineLimitAmt,
|
||||||
SUM(LineDiscountAmt) AS LineDiscountAmt,
|
SUM(LineDiscountAmt) AS LineDiscountAmt,
|
||||||
CASE WHEN SUM(LineListAmt)=0 THEN 0 ELSE
|
CASE WHEN SUM(LineListAmt)=0 THEN 0 ELSE
|
||||||
ROUND((SUM(LineListAmt)-SUM(LineNetAmt))/SUM(LineListAmt)*100,2) END AS LineDiscount,
|
currencyRound((SUM(LineListAmt)-SUM(LineNetAmt))/SUM(LineListAmt)*100,i.C_Currency_ID,'N') END AS LineDiscount,
|
||||||
SUM(LineOverLimitAmt) AS LineOverLimitAmt,
|
SUM(LineOverLimitAmt) AS LineOverLimitAmt,
|
||||||
CASE WHEN SUM(LineNetAmt)=0 THEN 0 ELSE
|
CASE WHEN SUM(LineNetAmt)=0 THEN 0 ELSE
|
||||||
100-ROUND((SUM(LineNetAmt)-SUM(LineOverLimitAmt))/SUM(LineNetAmt)*100,2) END AS LineOverLimit,
|
100-currencyRound((SUM(LineNetAmt)-SUM(LineOverLimitAmt))/SUM(LineNetAmt)*100,i.C_Currency_ID,'N') END AS LineOverLimit,
|
||||||
SUM(QtyInvoiced) AS QtyInvoiced, IsSOTrx
|
SUM(QtyInvoiced) AS QtyInvoiced, il.IsSOTrx
|
||||||
FROM RV_C_InvoiceLine il
|
FROM RV_C_InvoiceLine il
|
||||||
|
INNER JOIN C_Invoice i ON (i.C_Invoice_ID=il.C_Invoice_ID)
|
||||||
GROUP BY il.AD_Client_ID, il.AD_Org_ID, il.C_BPartner_ID, il.M_Product_Category_ID,
|
GROUP BY il.AD_Client_ID, il.AD_Org_ID, il.C_BPartner_ID, il.M_Product_Category_ID,
|
||||||
firstOf(il.DateInvoiced, 'Q'), IsSOTrx;
|
firstOf(il.DateInvoiced, 'Q'), il.IsSOTrx, i.C_Currency_ID;
|
||||||
|
|
||||||
|
|
||||||
|
|
||||||
|
|
|
@ -11,16 +11,17 @@ SELECT il.AD_Client_ID, il.AD_Org_ID,
|
||||||
SUM(LineLimitAmt) AS LineLimitAmt,
|
SUM(LineLimitAmt) AS LineLimitAmt,
|
||||||
SUM(LineDiscountAmt) AS LineDiscountAmt,
|
SUM(LineDiscountAmt) AS LineDiscountAmt,
|
||||||
CASE WHEN SUM(LineListAmt)=0 THEN 0 ELSE
|
CASE WHEN SUM(LineListAmt)=0 THEN 0 ELSE
|
||||||
ROUND((SUM(LineListAmt)-SUM(LineNetAmt))/SUM(LineListAmt)*100,2) END AS LineDiscount,
|
currencyRound((SUM(LineListAmt)-SUM(LineNetAmt))/SUM(LineListAmt)*100,i.C_Currency_ID,'N') END AS LineDiscount,
|
||||||
SUM(LineOverLimitAmt) AS LineOverLimitAmt,
|
SUM(LineOverLimitAmt) AS LineOverLimitAmt,
|
||||||
CASE WHEN SUM(LineNetAmt)=0 THEN 0 ELSE
|
CASE WHEN SUM(LineNetAmt)=0 THEN 0 ELSE
|
||||||
100-ROUND((SUM(LineNetAmt)-SUM(LineOverLimitAmt))/SUM(LineNetAmt)*100,2) END AS LineOverLimit,
|
100-currencyRound((SUM(LineNetAmt)-SUM(LineOverLimitAmt))/SUM(LineNetAmt)*100,i.C_Currency_ID,'N') END AS LineOverLimit,
|
||||||
SUM(QtyInvoiced) AS QtyInvoiced
|
SUM(QtyInvoiced) AS QtyInvoiced
|
||||||
FROM RV_C_InvoiceLine il
|
FROM RV_C_InvoiceLine il
|
||||||
INNER JOIN M_Product_PO po ON (il.M_Product_ID=po.M_Product_ID)
|
INNER JOIN C_Invoice i ON (i.C_Invoice_ID=il.C_Invoice_ID)
|
||||||
|
INNER JOIN M_Product_PO po ON (il.M_Product_ID=po.M_Product_ID)
|
||||||
WHERE il.IsSOTrx='Y'
|
WHERE il.IsSOTrx='Y'
|
||||||
GROUP BY il.AD_Client_ID, il.AD_Org_ID, il.C_BPartner_ID, po.C_BPartner_ID,
|
GROUP BY il.AD_Client_ID, il.AD_Org_ID, il.C_BPartner_ID, po.C_BPartner_ID,
|
||||||
firstOf(il.DateInvoiced, 'Q');
|
firstOf(il.DateInvoiced, 'Q'), i.C_Currency_ID;
|
||||||
|
|
||||||
|
|
||||||
|
|
||||||
|
|
|
@ -3,21 +3,22 @@ CREATE OR REPLACE VIEW RV_C_INVOICE_DAY
|
||||||
LINELISTAMT, LINELIMITAMT, LINEDISCOUNTAMT, LINEDISCOUNT, LINEOVERLIMITAMT,
|
LINELISTAMT, LINELIMITAMT, LINEDISCOUNTAMT, LINEDISCOUNT, LINEOVERLIMITAMT,
|
||||||
LINEOVERLIMIT, ISSOTRX)
|
LINEOVERLIMIT, ISSOTRX)
|
||||||
AS
|
AS
|
||||||
SELECT AD_Client_ID, AD_Org_ID, SalesRep_ID,
|
SELECT il.AD_Client_ID, il.AD_Org_ID, il.SalesRep_ID,
|
||||||
firstOf(DateInvoiced, 'DD') AS DateInvoiced, -- DD Day, DY Week, MM Month
|
firstOf(il.DateInvoiced, 'DD') AS DateInvoiced, -- DD Day, DY Week, MM Month
|
||||||
SUM(LineNetAmt) AS LineNetAmt,
|
SUM(LineNetAmt) AS LineNetAmt,
|
||||||
SUM(LineListAmt) AS LineListAmt,
|
SUM(LineListAmt) AS LineListAmt,
|
||||||
SUM(LineLimitAmt) AS LineLimitAmt,
|
SUM(LineLimitAmt) AS LineLimitAmt,
|
||||||
SUM(LineDiscountAmt) AS LineDiscountAmt,
|
SUM(LineDiscountAmt) AS LineDiscountAmt,
|
||||||
CASE WHEN SUM(LineListAmt)=0 THEN 0 ELSE
|
CASE WHEN SUM(LineListAmt)=0 THEN 0 ELSE
|
||||||
ROUND((SUM(LineListAmt)-SUM(LineNetAmt))/SUM(LineListAmt)*100,2) END AS LineDiscount,
|
currencyRound((SUM(LineListAmt)-SUM(LineNetAmt))/SUM(LineListAmt)*100,i.C_Currency_ID,'N') END AS LineDiscount,
|
||||||
SUM(LineOverLimitAmt) AS LineOverLimitAmt,
|
SUM(LineOverLimitAmt) AS LineOverLimitAmt,
|
||||||
CASE WHEN SUM(LineNetAmt)=0 THEN 0 ELSE
|
CASE WHEN SUM(LineNetAmt)=0 THEN 0 ELSE
|
||||||
100-ROUND((SUM(LineNetAmt)-SUM(LineOverLimitAmt))/SUM(LineNetAmt)*100,2) END AS LineOverLimit,
|
100-currencyRound((SUM(LineNetAmt)-SUM(LineOverLimitAmt))/SUM(LineNetAmt)*100,i.C_Currency_ID,'N') END AS LineOverLimit,
|
||||||
IsSOTrx
|
il.IsSOTrx
|
||||||
FROM RV_C_InvoiceLine
|
FROM RV_C_InvoiceLine il
|
||||||
GROUP BY AD_Client_ID, AD_Org_ID, SalesRep_ID,
|
INNER JOIN C_Invoice i ON (i.C_Invoice_ID=il.C_Invoice_ID)
|
||||||
firstOf(DateInvoiced, 'DD'), IsSOTrx;
|
GROUP BY il.AD_Client_ID, il.AD_Org_ID, il.SalesRep_ID,
|
||||||
|
firstOf(il.DateInvoiced, 'DD'), il.IsSOTrx, i.C_Currency_ID;
|
||||||
|
|
||||||
|
|
||||||
|
|
||||||
|
|
|
@ -3,21 +3,22 @@ CREATE OR REPLACE VIEW RV_C_INVOICE_MONTH
|
||||||
LINELISTAMT, LINELIMITAMT, LINEDISCOUNTAMT, LINEDISCOUNT, LINEOVERLIMITAMT,
|
LINELISTAMT, LINELIMITAMT, LINEDISCOUNTAMT, LINEDISCOUNT, LINEOVERLIMITAMT,
|
||||||
LINEOVERLIMIT, ISSOTRX)
|
LINEOVERLIMIT, ISSOTRX)
|
||||||
AS
|
AS
|
||||||
SELECT AD_Client_ID, AD_Org_ID, SalesRep_ID,
|
SELECT il.AD_Client_ID, il.AD_Org_ID, il.SalesRep_ID,
|
||||||
firstOf(DateInvoiced, 'MM') AS DateInvoiced, -- DD Day, DY Week, MM Month
|
firstOf(il.DateInvoiced, 'MM') AS DateInvoiced, -- DD Day, DY Week, MM Month
|
||||||
SUM(LineNetAmt) AS LineNetAmt,
|
SUM(LineNetAmt) AS LineNetAmt,
|
||||||
SUM(LineListAmt) AS LineListAmt,
|
SUM(LineListAmt) AS LineListAmt,
|
||||||
SUM(LineLimitAmt) AS LineLimitAmt,
|
SUM(LineLimitAmt) AS LineLimitAmt,
|
||||||
SUM(LineDiscountAmt) AS LineDiscountAmt,
|
SUM(LineDiscountAmt) AS LineDiscountAmt,
|
||||||
CASE WHEN SUM(LineListAmt)=0 THEN 0 ELSE
|
CASE WHEN SUM(LineListAmt)=0 THEN 0 ELSE
|
||||||
ROUND((SUM(LineListAmt)-SUM(LineNetAmt))/SUM(LineListAmt)*100,2) END AS LineDiscount,
|
currencyRound((SUM(LineListAmt)-SUM(LineNetAmt))/SUM(LineListAmt)*100,i.C_Currency_ID,'N') END AS LineDiscount,
|
||||||
SUM(LineOverLimitAmt) AS LineOverLimitAmt,
|
SUM(LineOverLimitAmt) AS LineOverLimitAmt,
|
||||||
CASE WHEN SUM(LineNetAmt)=0 THEN 0 ELSE
|
CASE WHEN SUM(LineNetAmt)=0 THEN 0 ELSE
|
||||||
100-ROUND((SUM(LineNetAmt)-SUM(LineOverLimitAmt))/SUM(LineNetAmt)*100,2) END AS LineOverLimit,
|
100-currencyRound((SUM(LineNetAmt)-SUM(LineOverLimitAmt))/SUM(LineNetAmt)*100,i.C_Currency_ID,'N') END AS LineOverLimit,
|
||||||
IsSOTrx
|
il.IsSOTrx
|
||||||
FROM RV_C_InvoiceLine
|
FROM RV_C_InvoiceLine il
|
||||||
GROUP BY AD_Client_ID, AD_Org_ID, SalesRep_ID,
|
INNER JOIN C_Invoice i ON (i.C_Invoice_ID=il.C_Invoice_ID)
|
||||||
firstOf(DateInvoiced, 'MM'), IsSOTrx;
|
GROUP BY il.AD_Client_ID, il.AD_Org_ID, il.SalesRep_ID,
|
||||||
|
firstOf(il.DateInvoiced, 'MM'), il.IsSOTrx, i.C_Currency_ID;
|
||||||
|
|
||||||
|
|
||||||
|
|
||||||
|
|
|
@ -10,14 +10,15 @@ SELECT il.AD_Client_ID, il.AD_Org_ID, il.M_Product_Category_ID,
|
||||||
SUM(il.LineLimitAmt) AS LineLimitAmt,
|
SUM(il.LineLimitAmt) AS LineLimitAmt,
|
||||||
SUM(il.LineDiscountAmt) AS LineDiscountAmt,
|
SUM(il.LineDiscountAmt) AS LineDiscountAmt,
|
||||||
CASE WHEN SUM(LineListAmt)=0 THEN 0 ELSE
|
CASE WHEN SUM(LineListAmt)=0 THEN 0 ELSE
|
||||||
ROUND((SUM(LineListAmt)-SUM(LineNetAmt))/SUM(LineListAmt)*100,2) END AS LineDiscount,
|
currencyRound((SUM(LineListAmt)-SUM(LineNetAmt))/SUM(LineListAmt)*100,i.C_Currency_ID,'N') END AS LineDiscount,
|
||||||
SUM(LineOverLimitAmt) AS LineOverLimitAmt,
|
SUM(LineOverLimitAmt) AS LineOverLimitAmt,
|
||||||
CASE WHEN SUM(LineNetAmt)=0 THEN 0 ELSE
|
CASE WHEN SUM(LineNetAmt)=0 THEN 0 ELSE
|
||||||
100-ROUND((SUM(LineNetAmt)-SUM(LineOverLimitAmt))/SUM(LineNetAmt)*100,2) END AS LineOverLimit,
|
100-currencyRound((SUM(LineNetAmt)-SUM(LineOverLimitAmt))/SUM(LineNetAmt)*100,i.C_Currency_ID,'N') END AS LineOverLimit,
|
||||||
SUM(QtyInvoiced) AS QtyInvoiced, IsSOTrx
|
SUM(QtyInvoiced) AS QtyInvoiced, il.IsSOTrx
|
||||||
FROM RV_C_InvoiceLine il
|
FROM RV_C_InvoiceLine il
|
||||||
|
INNER JOIN C_Invoice i ON (i.C_Invoice_ID=il.C_Invoice_ID)
|
||||||
GROUP BY il.AD_Client_ID, il.AD_Org_ID, il.M_Product_Category_ID,
|
GROUP BY il.AD_Client_ID, il.AD_Org_ID, il.M_Product_Category_ID,
|
||||||
firstOf(il.DateInvoiced, 'MM'), IsSOTrx;
|
firstOf(il.DateInvoiced, 'MM'), il.IsSOTrx, i.C_Currency_ID;
|
||||||
|
|
||||||
|
|
||||||
|
|
||||||
|
|
|
@ -10,14 +10,15 @@ SELECT il.AD_Client_ID, il.AD_Org_ID, il.M_Product_ID,
|
||||||
SUM(il.LineLimitAmt) AS LineLimitAmt,
|
SUM(il.LineLimitAmt) AS LineLimitAmt,
|
||||||
SUM(il.LineDiscountAmt) AS LineDiscountAmt,
|
SUM(il.LineDiscountAmt) AS LineDiscountAmt,
|
||||||
CASE WHEN SUM(LineListAmt)=0 THEN 0 ELSE
|
CASE WHEN SUM(LineListAmt)=0 THEN 0 ELSE
|
||||||
ROUND((SUM(LineListAmt)-SUM(LineNetAmt))/SUM(LineListAmt)*100,2) END AS LineDiscount,
|
currencyRound((SUM(LineListAmt)-SUM(LineNetAmt))/SUM(LineListAmt)*100,i.C_Currency_ID,'N') END AS LineDiscount,
|
||||||
SUM(LineOverLimitAmt) AS LineOverLimitAmt,
|
SUM(LineOverLimitAmt) AS LineOverLimitAmt,
|
||||||
CASE WHEN SUM(LineNetAmt)=0 THEN 0 ELSE
|
CASE WHEN SUM(LineNetAmt)=0 THEN 0 ELSE
|
||||||
100-ROUND((SUM(LineNetAmt)-SUM(LineOverLimitAmt))/SUM(LineNetAmt)*100,2) END AS LineOverLimit,
|
100-currencyRound((SUM(LineNetAmt)-SUM(LineOverLimitAmt))/SUM(LineNetAmt)*100,i.C_Currency_ID,'N') END AS LineOverLimit,
|
||||||
SUM(QtyInvoiced) AS QtyInvoiced, IsSOTrx
|
SUM(QtyInvoiced) AS QtyInvoiced, il.IsSOTrx
|
||||||
FROM RV_C_InvoiceLine il
|
FROM RV_C_InvoiceLine il
|
||||||
|
INNER JOIN C_Invoice i ON (i.C_Invoice_ID=il.C_Invoice_ID)
|
||||||
GROUP BY il.AD_Client_ID, il.AD_Org_ID, il.M_Product_ID,
|
GROUP BY il.AD_Client_ID, il.AD_Org_ID, il.M_Product_ID,
|
||||||
firstOf(il.DateInvoiced, 'MM'), IsSOTrx;
|
firstOf(il.DateInvoiced, 'MM'), il.IsSOTrx, i.C_Currency_ID;
|
||||||
|
|
||||||
|
|
||||||
|
|
||||||
|
|
|
@ -10,14 +10,15 @@ SELECT il.AD_Client_ID, il.AD_Org_ID, il.M_Product_ID,
|
||||||
SUM(il.LineLimitAmt) AS LineLimitAmt,
|
SUM(il.LineLimitAmt) AS LineLimitAmt,
|
||||||
SUM(il.LineDiscountAmt) AS LineDiscountAmt,
|
SUM(il.LineDiscountAmt) AS LineDiscountAmt,
|
||||||
CASE WHEN SUM(LineListAmt)=0 THEN 0 ELSE
|
CASE WHEN SUM(LineListAmt)=0 THEN 0 ELSE
|
||||||
ROUND((SUM(LineListAmt)-SUM(LineNetAmt))/SUM(LineListAmt)*100,2) END AS LineDiscount,
|
currencyRound((SUM(LineListAmt)-SUM(LineNetAmt))/SUM(LineListAmt)*100,i.C_Currency_ID,'N') END AS LineDiscount,
|
||||||
SUM(LineOverLimitAmt) AS LineOverLimitAmt,
|
SUM(LineOverLimitAmt) AS LineOverLimitAmt,
|
||||||
CASE WHEN SUM(LineNetAmt)=0 THEN 0 ELSE
|
CASE WHEN SUM(LineNetAmt)=0 THEN 0 ELSE
|
||||||
100-ROUND((SUM(LineNetAmt)-SUM(LineOverLimitAmt))/SUM(LineNetAmt)*100,2) END AS LineOverLimit,
|
100-currencyRound((SUM(LineNetAmt)-SUM(LineOverLimitAmt))/SUM(LineNetAmt)*100,i.C_Currency_ID,'N') END AS LineOverLimit,
|
||||||
SUM(QtyInvoiced) AS QtyInvoiced, IsSOTrx
|
SUM(QtyInvoiced) AS QtyInvoiced, il.IsSOTrx
|
||||||
FROM RV_C_InvoiceLine il
|
FROM RV_C_InvoiceLine il
|
||||||
|
INNER JOIN C_Invoice i ON (i.C_Invoice_ID=il.C_Invoice_ID)
|
||||||
GROUP BY il.AD_Client_ID, il.AD_Org_ID, il.M_Product_ID,
|
GROUP BY il.AD_Client_ID, il.AD_Org_ID, il.M_Product_ID,
|
||||||
firstOf(il.DateInvoiced, 'Q'), IsSOTrx;
|
firstOf(il.DateInvoiced, 'Q'), il.IsSOTrx, i.C_Currency_ID;
|
||||||
|
|
||||||
|
|
||||||
|
|
||||||
|
|
|
@ -10,14 +10,15 @@ SELECT il.AD_Client_ID, il.AD_Org_ID, il.M_Product_Category_ID,
|
||||||
SUM(il.LineLimitAmt) AS LineLimitAmt,
|
SUM(il.LineLimitAmt) AS LineLimitAmt,
|
||||||
SUM(il.LineDiscountAmt) AS LineDiscountAmt,
|
SUM(il.LineDiscountAmt) AS LineDiscountAmt,
|
||||||
CASE WHEN SUM(LineListAmt)=0 THEN 0 ELSE
|
CASE WHEN SUM(LineListAmt)=0 THEN 0 ELSE
|
||||||
ROUND((SUM(LineListAmt)-SUM(LineNetAmt))/SUM(LineListAmt)*100,2) END AS LineDiscount,
|
currencyRound((SUM(LineListAmt)-SUM(LineNetAmt))/SUM(LineListAmt)*100,i.C_Currency_ID,'N') END AS LineDiscount,
|
||||||
SUM(LineOverLimitAmt) AS LineOverLimitAmt,
|
SUM(LineOverLimitAmt) AS LineOverLimitAmt,
|
||||||
CASE WHEN SUM(LineNetAmt)=0 THEN 0 ELSE
|
CASE WHEN SUM(LineNetAmt)=0 THEN 0 ELSE
|
||||||
100-ROUND((SUM(LineNetAmt)-SUM(LineOverLimitAmt))/SUM(LineNetAmt)*100,2) END AS LineOverLimit,
|
100-currencyRound((SUM(LineNetAmt)-SUM(LineOverLimitAmt))/SUM(LineNetAmt)*100,i.C_Currency_ID,'N') END AS LineOverLimit,
|
||||||
SUM(QtyInvoiced) AS QtyInvoiced, IsSOTrx
|
SUM(QtyInvoiced) AS QtyInvoiced, il.IsSOTrx
|
||||||
FROM RV_C_InvoiceLine il
|
FROM RV_C_InvoiceLine il
|
||||||
|
INNER JOIN C_Invoice i ON (i.C_Invoice_ID=il.C_Invoice_ID)
|
||||||
GROUP BY il.AD_Client_ID, il.AD_Org_ID, il.M_Product_Category_ID,
|
GROUP BY il.AD_Client_ID, il.AD_Org_ID, il.M_Product_Category_ID,
|
||||||
firstOf(il.DateInvoiced, 'DY'), IsSOTrx;
|
firstOf(il.DateInvoiced, 'DY'), il.IsSOTrx, i.C_Currency_ID;
|
||||||
|
|
||||||
|
|
||||||
|
|
||||||
|
|
|
@ -6,21 +6,22 @@ AS
|
||||||
SELECT il.AD_Client_ID, il.AD_Org_ID,
|
SELECT il.AD_Client_ID, il.AD_Org_ID,
|
||||||
po.C_BPartner_ID, il.M_Product_Category_ID,
|
po.C_BPartner_ID, il.M_Product_Category_ID,
|
||||||
firstOf(il.DateInvoiced, 'MM') AS DateInvoiced, -- DD Day, DY Week, MM Month
|
firstOf(il.DateInvoiced, 'MM') AS DateInvoiced, -- DD Day, DY Week, MM Month
|
||||||
SUM(LineNetAmt) AS LineNetAmt,
|
SUM(il.LineNetAmt) AS LineNetAmt,
|
||||||
SUM(LineListAmt) AS LineListAmt,
|
SUM(LineListAmt) AS LineListAmt,
|
||||||
SUM(LineLimitAmt) AS LineLimitAmt,
|
SUM(LineLimitAmt) AS LineLimitAmt,
|
||||||
SUM(LineDiscountAmt) AS LineDiscountAmt,
|
SUM(LineDiscountAmt) AS LineDiscountAmt,
|
||||||
CASE WHEN SUM(LineListAmt)=0 THEN 0 ELSE
|
CASE WHEN SUM(LineListAmt)=0 THEN 0 ELSE
|
||||||
ROUND((SUM(LineListAmt)-SUM(LineNetAmt))/SUM(LineListAmt)*100,2) END AS LineDiscount,
|
currencyRound((SUM(LineListAmt)-SUM(LineNetAmt))/SUM(LineListAmt)*100,i.C_Currency_ID,'N') END AS LineDiscount,
|
||||||
SUM(LineOverLimitAmt) AS LineOverLimitAmt,
|
SUM(LineOverLimitAmt) AS LineOverLimitAmt,
|
||||||
CASE WHEN SUM(LineNetAmt)=0 THEN 0 ELSE
|
CASE WHEN SUM(LineNetAmt)=0 THEN 0 ELSE
|
||||||
100-ROUND((SUM(LineNetAmt)-SUM(LineOverLimitAmt))/SUM(LineNetAmt)*100,2) END AS LineOverLimit,
|
100-currencyRound((SUM(LineNetAmt)-SUM(LineOverLimitAmt))/SUM(LineNetAmt)*100,i.C_Currency_ID,'N') END AS LineOverLimit,
|
||||||
SUM(QtyInvoiced) AS QtyInvoiced
|
SUM(QtyInvoiced) AS QtyInvoiced
|
||||||
FROM RV_C_InvoiceLine il
|
FROM RV_C_InvoiceLine il
|
||||||
|
INNER JOIN C_Invoice i ON (i.C_Invoice_ID=il.C_Invoice_ID)
|
||||||
INNER JOIN M_Product_PO po ON (il.M_Product_ID=po.M_Product_ID)
|
INNER JOIN M_Product_PO po ON (il.M_Product_ID=po.M_Product_ID)
|
||||||
WHERE il.IsSOTrx='Y'
|
WHERE il.IsSOTrx='Y'
|
||||||
GROUP BY il.AD_Client_ID, il.AD_Org_ID, po.C_BPartner_ID, il.M_Product_Category_ID,
|
GROUP BY il.AD_Client_ID, il.AD_Org_ID, po.C_BPartner_ID, il.M_Product_Category_ID,
|
||||||
firstOf(il.DateInvoiced, 'MM');
|
firstOf(il.DateInvoiced, 'MM'), i.C_Currency_ID;
|
||||||
|
|
||||||
|
|
||||||
|
|
||||||
|
|
|
@ -3,21 +3,22 @@ CREATE OR REPLACE VIEW RV_C_INVOICE_WEEK
|
||||||
LINELISTAMT, LINELIMITAMT, LINEDISCOUNTAMT, LINEDISCOUNT, LINEOVERLIMITAMT,
|
LINELISTAMT, LINELIMITAMT, LINEDISCOUNTAMT, LINEDISCOUNT, LINEOVERLIMITAMT,
|
||||||
LINEOVERLIMIT, ISSOTRX)
|
LINEOVERLIMIT, ISSOTRX)
|
||||||
AS
|
AS
|
||||||
SELECT AD_Client_ID, AD_Org_ID, SalesRep_ID,
|
SELECT il.AD_Client_ID, il.AD_Org_ID, il.SalesRep_ID,
|
||||||
firstOf(DateInvoiced, 'DY') AS DateInvoiced, -- DD Day, DY Week, MM Month
|
firstOf(il.DateInvoiced, 'DY') AS DateInvoiced, -- DD Day, DY Week, MM Month
|
||||||
SUM(LineNetAmt) AS LineNetAmt,
|
SUM(LineNetAmt) AS LineNetAmt,
|
||||||
SUM(LineListAmt) AS LineListAmt,
|
SUM(LineListAmt) AS LineListAmt,
|
||||||
SUM(LineLimitAmt) AS LineLimitAmt,
|
SUM(LineLimitAmt) AS LineLimitAmt,
|
||||||
SUM(LineDiscountAmt) AS LineDiscountAmt,
|
SUM(LineDiscountAmt) AS LineDiscountAmt,
|
||||||
CASE WHEN SUM(LineListAmt)=0 THEN 0 ELSE
|
CASE WHEN SUM(LineListAmt)=0 THEN 0 ELSE
|
||||||
ROUND((SUM(LineListAmt)-SUM(LineNetAmt))/SUM(LineListAmt)*100,2) END AS LineDiscount,
|
currencyRound((SUM(LineListAmt)-SUM(LineNetAmt))/SUM(LineListAmt)*100,i.C_Currency_ID,'N') END AS LineDiscount,
|
||||||
SUM(LineOverLimitAmt) AS LineOverLimitAmt,
|
SUM(LineOverLimitAmt) AS LineOverLimitAmt,
|
||||||
CASE WHEN SUM(LineNetAmt)=0 THEN 0 ELSE
|
CASE WHEN SUM(LineNetAmt)=0 THEN 0 ELSE
|
||||||
100-ROUND((SUM(LineNetAmt)-SUM(LineOverLimitAmt))/SUM(LineNetAmt)*100,2) END AS LineOverLimit,
|
100-currencyRound((SUM(LineNetAmt)-SUM(LineOverLimitAmt))/SUM(LineNetAmt)*100,i.C_Currency_ID,'N') END AS LineOverLimit,
|
||||||
IsSOTrx
|
il.IsSOTrx
|
||||||
FROM RV_C_InvoiceLine
|
FROM RV_C_InvoiceLine il
|
||||||
GROUP BY AD_Client_ID, AD_Org_ID, SalesRep_ID,
|
INNER JOIN C_Invoice i ON (i.C_Invoice_ID=il.C_Invoice_ID)
|
||||||
firstOf(DateInvoiced, 'DY'), IsSOTrx;
|
GROUP BY il.AD_Client_ID, il.AD_Org_ID, il.SalesRep_ID,
|
||||||
|
firstOf(il.DateInvoiced, 'DY'), il.IsSOTrx, i.C_Currency_ID;
|
||||||
|
|
||||||
|
|
||||||
|
|
||||||
|
|
|
@ -14,7 +14,7 @@ SELECT i.ad_org_id,
|
||||||
paymenttermduedate(i.c_paymentterm_id, i.dateinvoiced) AS duedate,
|
paymenttermduedate(i.c_paymentterm_id, i.dateinvoiced) AS duedate,
|
||||||
paymenttermduedays(i.c_paymentterm_id, i.dateinvoiced, getdate()) AS daysdue,
|
paymenttermduedays(i.c_paymentterm_id, i.dateinvoiced, getdate()) AS daysdue,
|
||||||
adddays(i.dateinvoiced, p.discountdays) AS discountdate,
|
adddays(i.dateinvoiced, p.discountdays) AS discountdate,
|
||||||
round(i.grandtotal * p.discount / 100, 2) AS discountamt,
|
currencyRound(i.grandtotal * p.discount / 100,i.C_Currency_ID,'N') AS discountamt,
|
||||||
i.grandtotal,
|
i.grandtotal,
|
||||||
invoicepaid(i.c_invoice_id, i.c_currency_id, 1) AS paidamt,
|
invoicepaid(i.c_invoice_id, i.c_currency_id, 1) AS paidamt,
|
||||||
invoiceopen(i.c_invoice_id, 0) AS openamt,
|
invoiceopen(i.c_invoice_id, 0) AS openamt,
|
||||||
|
|
|
@ -14,7 +14,7 @@ SELECT i.AD_Org_ID, i.AD_Client_ID,
|
||||||
paymentTermDueDate(i.C_PaymentTerm_ID, i.DateInvoiced) AS DueDate,
|
paymentTermDueDate(i.C_PaymentTerm_ID, i.DateInvoiced) AS DueDate,
|
||||||
paymentTermDueDays(i.C_PaymentTerm_ID, i.DateInvoiced, getdate()) AS DaysDue,
|
paymentTermDueDays(i.C_PaymentTerm_ID, i.DateInvoiced, getdate()) AS DaysDue,
|
||||||
addDays(i.DateInvoiced,p.DiscountDays) AS DiscountDate,
|
addDays(i.DateInvoiced,p.DiscountDays) AS DiscountDate,
|
||||||
ROUND(i.GrandTotal*p.Discount/100,2) AS DiscountAmt,
|
currencyRound(i.GrandTotal*p.Discount/100,i.C_Currency_ID,'N') AS DiscountAmt,
|
||||||
i.GrandTotal,
|
i.GrandTotal,
|
||||||
--invoicePaid(i.C_Invoice_ID, i.C_Currency_ID, 1) AS PaidAmt,
|
--invoicePaid(i.C_Invoice_ID, i.C_Currency_ID, 1) AS PaidAmt,
|
||||||
--invoiceOpen(i.C_Invoice_ID,0) AS OpenAmt,
|
--invoiceOpen(i.C_Invoice_ID,0) AS OpenAmt,
|
||||||
|
|
|
@ -55,8 +55,8 @@ SELECT l.ad_client_id,
|
||||||
(l.qtyordered - l.qtyinvoiced) * l.priceactual AS netamttoinvoice,
|
(l.qtyordered - l.qtyinvoiced) * l.priceactual AS netamttoinvoice,
|
||||||
l.qtylostsales,
|
l.qtylostsales,
|
||||||
l.qtylostsales * l.priceactual AS amtlostsales,
|
l.qtylostsales * l.priceactual AS amtlostsales,
|
||||||
CASE WHEN l.pricelist = 0 THEN 0 ELSE round((l.pricelist - l.priceactual) / l.pricelist * 100, 2) END AS discount,
|
CASE WHEN l.pricelist = 0 THEN 0 ELSE currencyRound((l.pricelist - l.priceactual) / l.pricelist * 100,o.C_Currency_ID,'N') END AS discount,
|
||||||
CASE WHEN l.pricelimit = 0 THEN 0 ELSE round((l.priceactual - l.pricelimit) / l.pricelimit * 100, 2) END AS margin,
|
CASE WHEN l.pricelimit = 0 THEN 0 ELSE currencyRound((l.priceactual - l.pricelimit) / l.pricelimit * 100,o.C_Currency_ID,'N') END AS margin,
|
||||||
CASE WHEN l.pricelimit = 0 THEN 0 ELSE (l.priceactual - l.pricelimit) * l.qtydelivered END AS marginamt,
|
CASE WHEN l.pricelimit = 0 THEN 0 ELSE (l.priceactual - l.pricelimit) * l.qtydelivered END AS marginamt,
|
||||||
o.ad_org_id AS c_order_ad_org_id,
|
o.ad_org_id AS c_order_ad_org_id,
|
||||||
o.ad_orgtrx_id AS c_order_ad_orgtrx_id,
|
o.ad_orgtrx_id AS c_order_ad_orgtrx_id,
|
||||||
|
|
File diff suppressed because it is too large
Load Diff
File diff suppressed because it is too large
Load Diff
Loading…
Reference in New Issue