diff --git a/db/ddlutils/oracle/functions/BOM_PriceLimit.sql b/db/ddlutils/oracle/functions/BOM_PriceLimit.sql index fa1996fd77..37733c93fe 100644 --- a/db/ddlutils/oracle/functions/BOM_PriceLimit.sql +++ b/db/ddlutils/oracle/functions/BOM_PriceLimit.sql @@ -26,8 +26,10 @@ AS FROM M_PRODUCT_BOM b, M_PRODUCT p WHERE b.M_ProductBOM_ID=p.M_Product_ID AND b.M_Product_ID=Product_ID + AND b.M_ProductBOM_ID != Product_ID AND p.IsBOM='Y' - AND p.IsVerified='Y'; + AND p.IsVerified='Y' + AND b.IsActive='Y'; -- BEGIN -- Try to get price from PriceList directly diff --git a/db/ddlutils/oracle/functions/BOM_PriceList.sql b/db/ddlutils/oracle/functions/BOM_PriceList.sql index 0be86221b8..da274c35d8 100644 --- a/db/ddlutils/oracle/functions/BOM_PriceList.sql +++ b/db/ddlutils/oracle/functions/BOM_PriceList.sql @@ -26,8 +26,10 @@ AS FROM M_PRODUCT_BOM b, M_PRODUCT p WHERE b.M_ProductBOM_ID=p.M_Product_ID AND b.M_Product_ID=Product_ID + AND b.M_ProductBOM_ID != Product_ID AND p.IsBOM='Y' - AND p.IsVerified='Y'; + AND p.IsVerified='Y' + AND b.IsActive='Y'; -- BEGIN -- Try to get price from pricelist directly diff --git a/db/ddlutils/oracle/functions/BOM_PriceStd.sql b/db/ddlutils/oracle/functions/BOM_PriceStd.sql index e946334252..eace5db30a 100644 --- a/db/ddlutils/oracle/functions/BOM_PriceStd.sql +++ b/db/ddlutils/oracle/functions/BOM_PriceStd.sql @@ -26,8 +26,10 @@ AS FROM M_PRODUCT_BOM b, M_PRODUCT p WHERE b.M_ProductBOM_ID=p.M_Product_ID AND b.M_Product_ID=Product_ID + AND b.M_ProductBOM_ID != Product_ID AND p.IsBOM='Y' - AND p.IsVerified='Y'; + AND p.IsVerified='Y' + AND b.IsActive='Y'; -- BEGIN -- Try to get price from pricelist directly diff --git a/db/ddlutils/oracle/functions/BOM_Qty_OnHand.sql b/db/ddlutils/oracle/functions/BOM_Qty_OnHand.sql index aee834d042..8234cad33d 100644 --- a/db/ddlutils/oracle/functions/BOM_Qty_OnHand.sql +++ b/db/ddlutils/oracle/functions/BOM_Qty_OnHand.sql @@ -27,8 +27,10 @@ AS FROM M_PRODUCT_BOM b, M_PRODUCT p WHERE b.M_ProductBOM_ID=p.M_Product_ID AND b.M_Product_ID=Product_ID + AND b.M_ProductBOM_ID != Product_ID AND p.IsBOM='Y' - AND p.IsVerified='Y'; + AND p.IsVerified='Y' + AND b.IsActive='Y'; -- BEGIN -- Check Parameters diff --git a/db/ddlutils/oracle/functions/BOM_Qty_Ordered.sql b/db/ddlutils/oracle/functions/BOM_Qty_Ordered.sql index c0eb2b93ea..3fb7ec0651 100644 --- a/db/ddlutils/oracle/functions/BOM_Qty_Ordered.sql +++ b/db/ddlutils/oracle/functions/BOM_Qty_Ordered.sql @@ -27,8 +27,10 @@ AS FROM M_PRODUCT_BOM b, M_PRODUCT p WHERE b.M_ProductBOM_ID=p.M_Product_ID AND b.M_Product_ID=p_Product_ID + AND b.M_ProductBOM_ID != p_Product_ID AND p.IsBOM='Y' - AND p.IsVerified='Y'; + AND p.IsVerified='Y' + AND b.IsActive='Y'; -- BEGIN -- Check Parameters diff --git a/db/ddlutils/oracle/functions/BOM_Qty_Reserved.sql b/db/ddlutils/oracle/functions/BOM_Qty_Reserved.sql index 3cb43168ac..1d07949d8d 100644 --- a/db/ddlutils/oracle/functions/BOM_Qty_Reserved.sql +++ b/db/ddlutils/oracle/functions/BOM_Qty_Reserved.sql @@ -27,8 +27,10 @@ AS FROM M_PRODUCT_BOM b, M_PRODUCT p WHERE b.M_ProductBOM_ID=p.M_Product_ID AND b.M_Product_ID=p_Product_ID + AND b.M_ProductBOM_ID != p_Product_ID AND p.IsBOM='Y' - AND p.IsVerified='Y'; + AND p.IsVerified='Y' + AND b.IsActive='Y'; -- BEGIN -- Check Parameters diff --git a/db/ddlutils/postgresql/functions/BOM_PriceLimit.sql b/db/ddlutils/postgresql/functions/BOM_PriceLimit.sql index f32ba35945..f9c1b0b4b9 100644 --- a/db/ddlutils/postgresql/functions/BOM_PriceLimit.sql +++ b/db/ddlutils/postgresql/functions/BOM_PriceLimit.sql @@ -19,8 +19,10 @@ BEGIN FROM M_Product_BOM b, M_Product p WHERE b.M_ProductBOM_ID=p.M_Product_ID AND b.M_Product_ID=Product_ID + AND b.M_ProductBOM_ID != Product_ID AND p.IsBOM='Y' AND p.IsVerified='Y' + AND b.IsActive='Y' LOOP v_ProductPrice := bomPriceLimit (bom.M_ProductBOM_ID, PriceList_Version_ID); v_Price := v_Price + (bom.BOMQty * v_ProductPrice); @@ -32,6 +34,6 @@ BEGIN END; $BODY$ -LANGUAGE 'plpgsql' +LANGUAGE 'plpgsql' STABLE ; diff --git a/db/ddlutils/postgresql/functions/BOM_PriceList.sql b/db/ddlutils/postgresql/functions/BOM_PriceList.sql index 58aaef8ec6..8677da115c 100644 --- a/db/ddlutils/postgresql/functions/BOM_PriceList.sql +++ b/db/ddlutils/postgresql/functions/BOM_PriceList.sql @@ -19,8 +19,10 @@ BEGIN FROM M_Product_BOM b, M_Product p WHERE b.M_ProductBOM_ID=p.M_Product_ID AND b.M_Product_ID=Product_ID + AND b.M_ProductBOM_ID != Product_ID AND p.IsBOM='Y' AND p.IsVerified='Y' + AND b.IsActive='Y' LOOP v_ProductPrice := bomPriceList (bom.M_ProductBOM_ID, PriceList_Version_ID); v_Price := v_Price + (bom.BOMQty * v_ProductPrice); @@ -32,6 +34,6 @@ BEGIN END; $BODY$ -LANGUAGE 'plpgsql' +LANGUAGE 'plpgsql' STABLE ; diff --git a/db/ddlutils/postgresql/functions/BOM_PriceStd.sql b/db/ddlutils/postgresql/functions/BOM_PriceStd.sql index a259dccefc..96c3dabf00 100644 --- a/db/ddlutils/postgresql/functions/BOM_PriceStd.sql +++ b/db/ddlutils/postgresql/functions/BOM_PriceStd.sql @@ -19,8 +19,10 @@ BEGIN FROM M_Product_BOM b, M_Product p WHERE b.M_ProductBOM_ID=p.M_Product_ID AND b.M_Product_ID=Product_ID + AND b.M_ProductBOM_ID != Product_ID AND p.IsBOM='Y' AND p.IsVerified='Y' + AND b.IsActive='Y' LOOP v_ProductPrice := bomPriceStd (bom.M_ProductBOM_ID, PriceList_Version_ID); v_Price := v_Price + (bom.BOMQty * v_ProductPrice); @@ -32,6 +34,6 @@ BEGIN END; $BODY$ -LANGUAGE 'plpgsql' +LANGUAGE 'plpgsql' STABLE ; diff --git a/db/ddlutils/postgresql/functions/BOM_Qty_Available.sql b/db/ddlutils/postgresql/functions/BOM_Qty_Available.sql index 19662e14b2..40952ccf98 100644 --- a/db/ddlutils/postgresql/functions/BOM_Qty_Available.sql +++ b/db/ddlutils/postgresql/functions/BOM_Qty_Available.sql @@ -4,6 +4,6 @@ BEGIN RETURN bomQtyOnHand(Product_ID, Warehouse_ID, Locator_ID) - bomQtyReserved(Product_ID, Warehouse_ID, Locator_ID); END; $BODY$ -LANGUAGE 'plpgsql' +LANGUAGE 'plpgsql' STABLE ; diff --git a/db/ddlutils/postgresql/functions/BOM_Qty_OnHand.sql b/db/ddlutils/postgresql/functions/BOM_Qty_OnHand.sql index 9518f30ebe..adeff6ec6f 100644 --- a/db/ddlutils/postgresql/functions/BOM_Qty_OnHand.sql +++ b/db/ddlutils/postgresql/functions/BOM_Qty_OnHand.sql @@ -25,7 +25,6 @@ BEGIN IF (myWarehouse_ID IS NULL) THEN RETURN 0; END IF; --- DBMS_OUTPUT.PUT_LINE(''Warehouse='' || myWarehouse_ID); -- Check, if product exists and if it is stocked BEGIN @@ -51,19 +50,19 @@ BEGIN AND EXISTS (SELECT * FROM M_LOCATOR l WHERE s.M_Locator_ID=l.M_Locator_ID AND l.M_Warehouse_ID=myWarehouse_ID); -- - -- DBMS_OUTPUT.PUT_LINE(''Qty='' || v_ProductQty); RETURN v_ProductQty; END IF; -- Go though BOM --- DBMS_OUTPUT.PUT_LINE(''BOM''); FOR bom IN -- Get BOM Product info SELECT b.M_ProductBOM_ID, b.BOMQty, p.IsBOM, p.IsStocked, p.ProductType FROM M_PRODUCT_BOM b, M_PRODUCT p WHERE b.M_ProductBOM_ID=p.M_Product_ID AND b.M_Product_ID=product_ID + AND b.M_ProductBOM_ID != Product_ID AND p.IsBOM='Y' AND p.IsVerified='Y' + AND b.IsActive='Y' LOOP -- Stocked Items "leaf node" IF (bom.ProductType = 'I' AND bom.IsStocked = 'Y') THEN @@ -107,6 +106,6 @@ BEGIN RETURN 0; END; $BODY$ -LANGUAGE 'plpgsql' +LANGUAGE 'plpgsql' STABLE ; diff --git a/db/ddlutils/postgresql/functions/BOM_Qty_Ordered.sql b/db/ddlutils/postgresql/functions/BOM_Qty_Ordered.sql index b82e7dc67b..79c0fda12e 100644 --- a/db/ddlutils/postgresql/functions/BOM_Qty_Ordered.sql +++ b/db/ddlutils/postgresql/functions/BOM_Qty_Ordered.sql @@ -61,8 +61,10 @@ BEGIN FROM M_PRODUCT_BOM b, M_PRODUCT p WHERE b.M_ProductBOM_ID=p.M_Product_ID AND b.M_Product_ID=p_Product_ID + AND b.M_ProductBOM_ID != p_Product_ID AND p.IsBOM='Y' AND p.IsVerified='Y' + AND b.IsActive='Y' LOOP -- Stocked Items "leaf node" IF (bom.ProductType = 'I' AND bom.IsStocked = 'Y') THEN @@ -114,5 +116,5 @@ BEGIN RETURN 0; END; $BODY$ - LANGUAGE plpgsql VOLATILE; + LANGUAGE plpgsql STABLE; diff --git a/db/ddlutils/postgresql/functions/BOM_Qty_Reserved.sql b/db/ddlutils/postgresql/functions/BOM_Qty_Reserved.sql index 22775b364b..2f2b4f428a 100644 --- a/db/ddlutils/postgresql/functions/BOM_Qty_Reserved.sql +++ b/db/ddlutils/postgresql/functions/BOM_Qty_Reserved.sql @@ -61,8 +61,10 @@ BEGIN FROM M_PRODUCT_BOM b, M_PRODUCT p WHERE b.M_ProductBOM_ID=p.M_Product_ID AND b.M_Product_ID=p_Product_ID + AND b.M_ProductBOM_ID != p_Product_ID AND p.IsBOM='Y' AND p.IsVerified='Y' + AND b.IsActive='Y' LOOP -- Stocked Items "leaf node" IF (bom.ProductType = 'I' AND bom.IsStocked = 'Y') THEN @@ -112,6 +114,6 @@ BEGIN RETURN 0; END; $BODY$ - LANGUAGE plpgsql VOLATILE; + LANGUAGE plpgsql STABLE; diff --git a/migration/i2.0/oracle/201405160521_IDEMPIERE-1953.sql b/migration/i2.0/oracle/201405160521_IDEMPIERE-1953.sql new file mode 100644 index 0000000000..1611acbf7a --- /dev/null +++ b/migration/i2.0/oracle/201405160521_IDEMPIERE-1953.sql @@ -0,0 +1,556 @@ +SET SQLBLANKLINES ON +SET DEFINE OFF + +CREATE OR REPLACE FUNCTION BOMPRICELIMIT +( + Product_ID IN NUMBER, + PriceList_Version_ID IN NUMBER +) +RETURN NUMBER +/************************************************************************* + * The contents of this file are subject to the Compiere License. You may + * obtain a copy of the License at http://www.compiere.org/license.html + * Software is on an "AS IS" basis, WITHOUT WARRANTY OF ANY KIND, either + * express or implied. See the License for details. Code: Compiere ERP+CRM + * Copyright (C) 1999-2002 Jorg Janke, ComPiere, Inc. All Rights Reserved. + ************************************************************************* + * $Id: BOM_PriceLimit.sql,v 1.1 2006/04/21 17:51:58 jjanke Exp $ + *** + * Title: Return Limit Price of Product/BOM + * Description: + * if not found: 0 + ************************************************************************/ +AS + v_Price NUMBER; + v_ProductPrice NUMBER; + -- Get BOM Product info + CURSOR CUR_BOM IS + SELECT b.M_ProductBOM_ID, b.BOMQty, p.IsBOM + FROM M_PRODUCT_BOM b, M_PRODUCT p + WHERE b.M_ProductBOM_ID=p.M_Product_ID + AND b.M_Product_ID=Product_ID + AND b.M_ProductBOM_ID != Product_ID + AND p.IsBOM='Y' + AND p.IsVerified='Y' + AND b.IsActive='Y'; + -- +BEGIN + -- Try to get price from PriceList directly + SELECT COALESCE (SUM(PriceLimit), 0) + INTO v_Price + FROM M_PRODUCTPRICE + WHERE M_PriceList_Version_ID=PriceList_Version_ID AND M_Product_ID=Product_ID; +-- DBMS_OUTPUT.PUT_LINE('Price=' || v_Price); + + -- No Price - Check if BOM + IF (v_Price = 0) THEN + FOR bom IN CUR_BOM LOOP + v_ProductPrice := Bompricelimit (bom.M_ProductBOM_ID, PriceList_Version_ID); + v_Price := v_Price + (bom.BOMQty * v_ProductPrice); + END LOOP; + END IF; + -- + RETURN v_Price; +END Bompricelimit; +/ + +CREATE OR REPLACE FUNCTION BOMPRICELIST +( + Product_ID IN NUMBER, + PriceList_Version_ID IN NUMBER +) +RETURN NUMBER +/************************************************************************* + * The contents of this file are subject to the Compiere License. You may + * obtain a copy of the License at http://www.compiere.org/license.html + * Software is on an "AS IS" basis, WITHOUT WARRANTY OF ANY KIND, either + * express or implied. See the License for details. Code: Compiere ERP+CRM + * Copyright (C) 1999-2002 Jorg Janke, ComPiere, Inc. All Rights Reserved. + ************************************************************************* + * $Id: BOM_PriceList.sql,v 1.1 2006/04/21 17:51:58 jjanke Exp $ + *** + * Title: Return List Price of Product/BOM + * Description: + * if not found: 0 + ************************************************************************/ +AS + v_Price NUMBER; + v_ProductPrice NUMBER; + -- Get BOM Product info + CURSOR CUR_BOM IS + SELECT b.M_ProductBOM_ID, b.BOMQty, p.IsBOM + FROM M_PRODUCT_BOM b, M_PRODUCT p + WHERE b.M_ProductBOM_ID=p.M_Product_ID + AND b.M_Product_ID=Product_ID + AND b.M_ProductBOM_ID != Product_ID + AND p.IsBOM='Y' + AND p.IsVerified='Y' + AND b.IsActive='Y'; + -- +BEGIN + -- Try to get price from pricelist directly + SELECT COALESCE (SUM(PriceList), 0) + INTO v_Price + FROM M_PRODUCTPRICE + WHERE M_PriceList_Version_ID=PriceList_Version_ID AND M_Product_ID=Product_ID; +-- DBMS_OUTPUT.PUT_LINE('Price=' || Price); + + -- No Price - Check if BOM + IF (v_Price = 0) THEN + FOR bom IN CUR_BOM LOOP + v_ProductPrice := Bompricelist (bom.M_ProductBOM_ID, PriceList_Version_ID); + v_Price := v_Price + (bom.BOMQty * v_ProductPrice); + -- DBMS_OUTPUT.PUT_LINE('Qry=' || bom.BOMQty || ' @ ' || v_ProductPrice || ', Price=' || v_Price); + END LOOP; -- BOM + END IF; + -- + RETURN v_Price; +END Bompricelist; +/ + +CREATE OR REPLACE FUNCTION BOMPRICESTD +( + Product_ID IN NUMBER, + PriceList_Version_ID IN NUMBER +) +RETURN NUMBER +/************************************************************************* + * The contents of this file are subject to the Compiere License. You may + * obtain a copy of the License at http://www.compiere.org/license.html + * Software is on an "AS IS" basis, WITHOUT WARRANTY OF ANY KIND, either + * express or implied. See the License for details. Code: Compiere ERP+CRM + * Copyright (C) 1999-2002 Jorg Janke, ComPiere, Inc. All Rights Reserved. + ************************************************************************* + * $Id: BOM_PriceStd.sql,v 1.1 2006/04/21 17:51:58 jjanke Exp $ + *** + * Title: Return Standard Price of Product/BOM + * Description: + * if not found: 0 + ************************************************************************/ +AS + v_Price NUMBER; + v_ProductPrice NUMBER; + -- Get BOM Product info + CURSOR CUR_BOM IS + SELECT b.M_ProductBOM_ID, b.BOMQty, p.IsBOM + FROM M_PRODUCT_BOM b, M_PRODUCT p + WHERE b.M_ProductBOM_ID=p.M_Product_ID + AND b.M_Product_ID=Product_ID + AND b.M_ProductBOM_ID != Product_ID + AND p.IsBOM='Y' + AND p.IsVerified='Y' + AND b.IsActive='Y'; + -- +BEGIN + -- Try to get price from pricelist directly + SELECT COALESCE(SUM(PriceStd), 0) + INTO v_Price + FROM M_PRODUCTPRICE + WHERE M_PriceList_Version_ID=PriceList_Version_ID AND M_Product_ID=Product_ID; +-- DBMS_OUTPUT.PUT_LINE('Price=' || v_Price); + + -- No Price - Check if BOM + IF (v_Price = 0) THEN + FOR bom IN CUR_BOM LOOP + v_ProductPrice := Bompricestd (bom.M_ProductBOM_ID, PriceList_Version_ID); + v_Price := v_Price + (bom.BOMQty * v_ProductPrice); + -- DBMS_OUTPUT.PUT_LINE('Price=' || v_Price); + END LOOP; -- BOM + END IF; + -- + RETURN v_Price; +END Bompricestd; +/ + +CREATE OR REPLACE FUNCTION BOMQTYONHAND +( + Product_ID IN NUMBER, + Warehouse_ID IN NUMBER, + Locator_ID IN NUMBER -- Only used, if warehouse is null +) +RETURN NUMBER +/****************************************************************************** + * ** Compiere Product ** Copyright (c) 1999-2001 Accorto, Inc. USA + * Open Source Software Provided "AS IS" without warranty or liability + * When you use any parts (changed or unchanged), add "Powered by Compiere" to + * your product name; See license details http://www.compiere.org/license.html + ****************************************************************************** + * Return quantity on hand for BOM + */ +AS + myWarehouse_ID NUMBER; + Quantity NUMBER := 99999; -- unlimited + IsBOM CHAR(1); + IsStocked CHAR(1); + ProductType CHAR(1); + ProductQty NUMBER; + StdPrecision NUMBER; + -- Get BOM Product info + CURSOR CUR_BOM IS + SELECT b.M_ProductBOM_ID, b.BOMQty, p.IsBOM, p.IsStocked, p.ProductType + FROM M_PRODUCT_BOM b, M_PRODUCT p + WHERE b.M_ProductBOM_ID=p.M_Product_ID + AND b.M_Product_ID=Product_ID + AND b.M_ProductBOM_ID != Product_ID + AND p.IsBOM='Y' + AND p.IsVerified='Y' + AND b.IsActive='Y'; + -- +BEGIN + -- Check Parameters + myWarehouse_ID := Warehouse_ID; + IF (myWarehouse_ID IS NULL) THEN + IF (Locator_ID IS NULL) THEN + RETURN 0; + ELSE + SELECT SUM(M_Warehouse_ID) INTO myWarehouse_ID + FROM M_LOCATOR + WHERE M_Locator_ID=Locator_ID; + END IF; + END IF; + IF (myWarehouse_ID IS NULL) THEN + RETURN 0; + END IF; +-- DBMS_OUTPUT.PUT_LINE('Warehouse=' || myWarehouse_ID); + + -- Check, if product exists and if it is stocked + BEGIN + SELECT IsBOM, ProductType, IsStocked + INTO IsBOM, ProductType, IsStocked + FROM M_PRODUCT + WHERE M_Product_ID=Product_ID; + -- + EXCEPTION -- not found + WHEN OTHERS THEN + RETURN 0; + END; + -- Unimited capacity if no item + IF (IsBOM='N' AND (ProductType<>'I' OR IsStocked='N')) THEN + RETURN Quantity; + -- Stocked item + ELSIF (IsStocked='Y') THEN + -- Get ProductQty + SELECT NVL(SUM(QtyOnHand), 0) + INTO ProductQty + FROM M_STORAGE s + WHERE M_Product_ID=Product_ID + AND EXISTS (SELECT * FROM M_LOCATOR l WHERE s.M_Locator_ID=l.M_Locator_ID + AND l.M_Warehouse_ID=myWarehouse_ID); + -- + -- DBMS_OUTPUT.PUT_LINE('Qty=' || ProductQty); + RETURN ProductQty; + END IF; + + -- Go though BOM +-- DBMS_OUTPUT.PUT_LINE('BOM'); + FOR bom IN CUR_BOM LOOP + -- Stocked Items "leaf node" + IF (bom.ProductType = 'I' AND bom.IsStocked = 'Y') THEN + -- Get ProductQty + SELECT NVL(SUM(QtyOnHand), 0) + INTO ProductQty + FROM M_STORAGE s + WHERE M_Product_ID=bom.M_ProductBOM_ID + AND EXISTS (SELECT * FROM M_LOCATOR l WHERE s.M_Locator_ID=l.M_Locator_ID + AND l.M_Warehouse_ID=myWarehouse_ID); + -- Get Rounding Precision + SELECT NVL(MAX(u.StdPrecision), 0) + INTO StdPrecision + FROM C_UOM u, M_PRODUCT p + WHERE u.C_UOM_ID=p.C_UOM_ID AND p.M_Product_ID=bom.M_ProductBOM_ID; + -- How much can we make with this product + ProductQty := ROUND (ProductQty/bom.BOMQty, StdPrecision); + -- How much can we make overall + IF (ProductQty < Quantity) THEN + Quantity := ProductQty; + END IF; + -- Another BOM + ELSIF (bom.IsBOM = 'Y') THEN + ProductQty := Bomqtyonhand (bom.M_ProductBOM_ID, myWarehouse_ID, Locator_ID); + -- How much can we make overall + IF (ProductQty < Quantity) THEN + Quantity := ProductQty; + END IF; + END IF; + END LOOP; -- BOM + + IF (Quantity > 0) THEN + -- Get Rounding Precision for Product + SELECT NVL(MAX(u.StdPrecision), 0) + INTO StdPrecision + FROM C_UOM u, M_PRODUCT p + WHERE u.C_UOM_ID=p.C_UOM_ID AND p.M_Product_ID=Product_ID; + -- + RETURN ROUND (Quantity, StdPrecision); + END IF; + RETURN 0; +END Bomqtyonhand; +/ + +CREATE OR REPLACE FUNCTION BOMQTYORDERED +( + p_Product_ID IN NUMBER, + p_Warehouse_ID IN NUMBER, + p_Locator_ID IN NUMBER -- Only used, if warehouse is null +) +RETURN NUMBER +/****************************************************************************** + * ** Compiere Product ** Copyright (c) 1999-2001 Accorto, Inc. USA + * Open Source Software Provided "AS IS" without warranty or liability + * When you use any parts (changed or unchanged), add "Powered by Compiere" to + * your product name; See license details http://www.compiere.org/license.html + ****************************************************************************** + * Return quantity ordered for BOM + */ +AS + v_Warehouse_ID NUMBER; + v_Quantity NUMBER := 99999; -- unlimited + v_IsBOM CHAR(1); + v_IsStocked CHAR(1); + v_ProductType CHAR(1); + v_ProductQty NUMBER; + v_StdPrecision NUMBER; + -- Get BOM Product info + CURSOR CUR_BOM IS + SELECT b.M_ProductBOM_ID, b.BOMQty, p.IsBOM, p.IsStocked, p.ProductType + FROM M_PRODUCT_BOM b, M_PRODUCT p + WHERE b.M_ProductBOM_ID=p.M_Product_ID + AND b.M_Product_ID=p_Product_ID + AND b.M_ProductBOM_ID != p_Product_ID + AND p.IsBOM='Y' + AND p.IsVerified='Y' + AND b.IsActive='Y'; + -- +BEGIN + -- Check Parameters + v_Warehouse_ID := p_Warehouse_ID; + IF (v_Warehouse_ID IS NULL) THEN + IF (p_Locator_ID IS NULL) THEN + RETURN 0; + ELSE + SELECT MAX(M_Warehouse_ID) INTO v_Warehouse_ID + FROM M_LOCATOR + WHERE M_Locator_ID=p_Locator_ID; + END IF; + END IF; + IF (v_Warehouse_ID IS NULL) THEN + RETURN 0; + END IF; +-- DBMS_OUTPUT.PUT_LINE('Warehouse=' || v_Warehouse_ID); + + -- Check, if product exists and if it is stocked + BEGIN + SELECT IsBOM, ProductType, IsStocked + INTO v_IsBOM, v_ProductType, v_IsStocked + FROM M_PRODUCT + WHERE M_Product_ID=p_Product_ID; + -- + EXCEPTION -- not found + WHEN OTHERS THEN + RETURN 0; + END; + + -- No reservation for non-stocked + IF (v_IsBOM='N' AND (v_ProductType<>'I' OR v_IsStocked='N')) THEN + RETURN 0; + -- Stocked item + ELSIF (v_IsStocked='Y') THEN + -- Get ProductQty + SELECT NVL(SUM(Qty), 0) + INTO v_ProductQty + FROM M_StorageReservation + WHERE M_Product_ID=p_Product_ID + AND M_Warehouse_ID=v_Warehouse_ID + AND IsSOTrx='N' + AND IsActive='Y'; + -- + RETURN v_ProductQty; + END IF; + + -- Go though BOM +-- DBMS_OUTPUT.PUT_LINE('BOM'); + FOR bom IN CUR_BOM LOOP + -- Stocked Items "leaf node" + IF (bom.ProductType = 'I' AND bom.IsStocked = 'Y') THEN + -- Get ProductQty + SELECT NVL(SUM(Qty), 0) + INTO v_ProductQty + FROM M_StorageReservation + WHERE M_Product_ID=p_Product_ID + AND M_Warehouse_ID=v_Warehouse_ID + AND IsSOTrx='N' + AND IsActive='Y'; + -- Get Rounding Precision + SELECT NVL(MAX(u.StdPrecision), 0) + INTO v_StdPrecision + FROM C_UOM u, M_PRODUCT p + WHERE u.C_UOM_ID=p.C_UOM_ID AND p.M_Product_ID=bom.M_ProductBOM_ID; + -- How much can we make with this product + v_ProductQty := ROUND (v_ProductQty/bom.BOMQty, v_StdPrecision); + -- How much can we make overall + IF (v_ProductQty < v_Quantity) THEN + v_Quantity := v_ProductQty; + END IF; + -- Another BOM + ELSIF (bom.IsBOM = 'Y') THEN + v_ProductQty := Bomqtyordered (bom.M_ProductBOM_ID, v_Warehouse_ID, p_Locator_ID); + -- How much can we make overall + IF (v_ProductQty < v_Quantity) THEN + v_Quantity := v_ProductQty; + END IF; + END IF; + END LOOP; -- BOM + + -- Unlimited (e.g. only services) + IF (v_Quantity = 99999) THEN + RETURN 0; + END IF; + + IF (v_Quantity > 0) THEN + -- Get Rounding Precision for Product + SELECT NVL(MAX(u.StdPrecision), 0) + INTO v_StdPrecision + FROM C_UOM u, M_PRODUCT p + WHERE u.C_UOM_ID=p.C_UOM_ID AND p.M_Product_ID=p_Product_ID; + -- + RETURN ROUND (v_Quantity, v_StdPrecision); + END IF; + -- + RETURN 0; +END Bomqtyordered; +/ + +CREATE OR REPLACE FUNCTION BOMQTYRESERVED +( + p_Product_ID IN NUMBER, + p_Warehouse_ID IN NUMBER, + p_Locator_ID IN NUMBER -- Only used, if warehouse is null +) +RETURN NUMBER +/****************************************************************************** + * ** Compiere Product ** Copyright (c) 1999-2001 Accorto, Inc. USA + * Open Source Software Provided "AS IS" without warranty or liability + * When you use any parts (changed or unchanged), add "Powered by Compiere" to + * your product name; See license details http://www.compiere.org/license.html + ****************************************************************************** + * Return quantity reserved for BOM + */ +AS + v_Warehouse_ID NUMBER; + v_Quantity NUMBER := 99999; -- unlimited + v_IsBOM CHAR(1); + v_IsStocked CHAR(1); + v_ProductType CHAR(1); + v_ProductQty NUMBER; + v_StdPrecision NUMBER; + -- Get BOM Product info + CURSOR CUR_BOM IS + SELECT b.M_ProductBOM_ID, b.BOMQty, p.IsBOM, p.IsStocked, p.ProductType + FROM M_PRODUCT_BOM b, M_PRODUCT p + WHERE b.M_ProductBOM_ID=p.M_Product_ID + AND b.M_Product_ID=p_Product_ID + AND b.M_ProductBOM_ID != p_Product_ID + AND p.IsBOM='Y' + AND p.IsVerified='Y' + AND b.IsActive='Y'; + -- +BEGIN + -- Check Parameters + v_Warehouse_ID := p_Warehouse_ID; + IF (v_Warehouse_ID IS NULL) THEN + IF (p_Locator_ID IS NULL) THEN + RETURN 0; + ELSE + SELECT MAX(M_Warehouse_ID) INTO v_Warehouse_ID + FROM M_LOCATOR + WHERE M_Locator_ID=p_Locator_ID; + END IF; + END IF; + IF (v_Warehouse_ID IS NULL) THEN + RETURN 0; + END IF; +-- DBMS_OUTPUT.PUT_LINE('Warehouse=' || v_Warehouse_ID); + + -- Check, if product exists and if it is stocked + BEGIN + SELECT IsBOM, ProductType, IsStocked + INTO v_IsBOM, v_ProductType, v_IsStocked + FROM M_PRODUCT + WHERE M_Product_ID=p_Product_ID; + -- + EXCEPTION -- not found + WHEN OTHERS THEN + RETURN 0; + END; + + -- No reservation for non-stocked + IF (v_IsBOM='N' AND (v_ProductType<>'I' OR v_IsStocked='N')) THEN + RETURN 0; + -- Stocked item + ELSIF (v_IsStocked='Y') THEN + -- Get ProductQty + SELECT NVL(SUM(Qty), 0) + INTO v_ProductQty + FROM M_StorageReservation + WHERE M_Product_ID=p_Product_ID + AND M_Warehouse_ID=v_Warehouse_ID + AND IsSOTrx='Y' + AND IsActive='Y'; + -- + RETURN v_ProductQty; + END IF; + + -- Go though BOM +-- DBMS_OUTPUT.PUT_LINE('BOM'); + FOR bom IN CUR_BOM LOOP + -- Stocked Items "leaf node" + IF (bom.ProductType = 'I' AND bom.IsStocked = 'Y') THEN + -- Get ProductQty + SELECT NVL(SUM(Qty), 0) + INTO v_ProductQty + FROM M_StorageReservation + WHERE M_Product_ID=bom.M_ProductBOM_ID + AND M_Warehouse_ID=v_Warehouse_ID + AND IsSOTrx='Y' + AND IsActive='Y'; + -- Get Rounding Precision + SELECT NVL(MAX(u.StdPrecision), 0) + INTO v_StdPrecision + FROM C_UOM u, M_PRODUCT p + WHERE u.C_UOM_ID=p.C_UOM_ID AND p.M_Product_ID=bom.M_ProductBOM_ID; + -- How much can we make with this product + v_ProductQty := ROUND (v_ProductQty/bom.BOMQty, v_StdPrecision); + -- How much can we make overall + IF (v_ProductQty < v_Quantity) THEN + v_Quantity := v_ProductQty; + END IF; + -- Another BOM + ELSIF (bom.IsBOM = 'Y') THEN + v_ProductQty := Bomqtyreserved (bom.M_ProductBOM_ID, v_Warehouse_ID, p_Locator_ID); + -- How much can we make overall + IF (v_ProductQty < v_Quantity) THEN + v_Quantity := v_ProductQty; + END IF; + END IF; + END LOOP; -- BOM + + -- Unlimited (e.g. only services) + IF (v_Quantity = 99999) THEN + RETURN 0; + END IF; + + IF (v_Quantity > 0) THEN + -- Get Rounding Precision for Product + SELECT NVL(MAX(u.StdPrecision), 0) + INTO v_StdPrecision + FROM C_UOM u, M_PRODUCT p + WHERE u.C_UOM_ID=p.C_UOM_ID AND p.M_Product_ID=p_Product_ID; + -- + RETURN ROUND (v_Quantity, v_StdPrecision); + END IF; + RETURN 0; +END Bomqtyreserved; +/ + +SELECT register_migration_script('201405160521_IDEMPIERE-1953.sql') FROM dual +; diff --git a/migration/i2.0/postgresql/201405160521_IDEMPIERE-1953.sql b/migration/i2.0/postgresql/201405160521_IDEMPIERE-1953.sql new file mode 100644 index 0000000000..3fbf47afdd --- /dev/null +++ b/migration/i2.0/postgresql/201405160521_IDEMPIERE-1953.sql @@ -0,0 +1,478 @@ +CREATE OR REPLACE FUNCTION bompricelimit (in product_id numeric, in pricelist_version_id numeric) RETURNS numeric AS +$BODY$ +DECLARE + v_Price NUMERIC; + v_ProductPrice NUMERIC; + bom RECORD; + +BEGIN + -- Try to get price from PriceList directly + SELECT COALESCE (SUM(PriceLimit), 0) + INTO v_Price + FROM M_ProductPrice + WHERE M_PriceList_Version_ID=PriceList_Version_ID AND M_Product_ID=Product_ID; + + -- No Price - Check if BOM + IF (v_Price = 0) THEN + FOR bom IN + SELECT b.M_ProductBOM_ID, b.BOMQty, p.IsBOM + FROM M_Product_BOM b, M_Product p + WHERE b.M_ProductBOM_ID=p.M_Product_ID + AND b.M_Product_ID=Product_ID + AND b.M_ProductBOM_ID != Product_ID + AND p.IsBOM='Y' + AND p.IsVerified='Y' + AND b.IsActive='Y' + LOOP + v_ProductPrice := bomPriceLimit (bom.M_ProductBOM_ID, PriceList_Version_ID); + v_Price := v_Price + (bom.BOMQty * v_ProductPrice); + END LOOP; + END IF; + -- + RETURN v_Price; + +END; + +$BODY$ +LANGUAGE 'plpgsql' STABLE +; + +CREATE OR REPLACE FUNCTION bompricelist (in product_id numeric, in pricelist_version_id numeric) RETURNS numeric AS +$BODY$ +DECLARE + v_Price NUMERIC; + v_ProductPrice NUMERIC; + bom RECORD; + +BEGIN + -- Try to get price from pricelist directly + SELECT COALESCE (SUM(PriceList), 0) + INTO v_Price + FROM M_ProductPrice + WHERE M_PriceList_Version_ID=PriceList_Version_ID AND M_Product_ID=Product_ID; + + -- No Price - Check if BOM + IF (v_Price = 0) THEN + FOR bom IN + SELECT b.M_ProductBOM_ID, b.BOMQty, p.IsBOM + FROM M_Product_BOM b, M_Product p + WHERE b.M_ProductBOM_ID=p.M_Product_ID + AND b.M_Product_ID=Product_ID + AND b.M_ProductBOM_ID != Product_ID + AND p.IsBOM='Y' + AND p.IsVerified='Y' + AND b.IsActive='Y' + LOOP + v_ProductPrice := bomPriceList (bom.M_ProductBOM_ID, PriceList_Version_ID); + v_Price := v_Price + (bom.BOMQty * v_ProductPrice); + END LOOP; + END IF; + -- + RETURN v_Price; + +END; + +$BODY$ +LANGUAGE 'plpgsql' STABLE +; + +CREATE OR REPLACE FUNCTION bompricestd (in product_id numeric, in pricelist_version_id numeric) RETURNS numeric AS +$BODY$ +DECLARE + v_Price NUMERIC; + v_ProductPrice NUMERIC; + bom RECORD; + +BEGIN + -- Try to get price from PriceList directly + SELECT COALESCE(SUM(PriceStd), 0) + INTO v_Price + FROM M_ProductPrice + WHERE M_PriceList_Version_ID=PriceList_Version_ID AND M_Product_ID=Product_ID; + + -- No Price - Check if BOM + IF (v_Price = 0) THEN + FOR bom IN + SELECT b.M_ProductBOM_ID, b.BOMQty, p.IsBOM + FROM M_Product_BOM b, M_Product p + WHERE b.M_ProductBOM_ID=p.M_Product_ID + AND b.M_Product_ID=Product_ID + AND b.M_ProductBOM_ID != Product_ID + AND p.IsBOM='Y' + AND p.IsVerified='Y' + AND b.IsActive='Y' + LOOP + v_ProductPrice := bomPriceStd (bom.M_ProductBOM_ID, PriceList_Version_ID); + v_Price := v_Price + (bom.BOMQty * v_ProductPrice); + END LOOP; + END IF; + -- + RETURN v_Price; + +END; + +$BODY$ +LANGUAGE 'plpgsql' STABLE +; + +CREATE OR REPLACE FUNCTION bomqtyavailable (in product_id numeric, in warehouse_id numeric, in locator_id numeric) RETURNS numeric AS +$BODY$ +BEGIN + RETURN bomQtyOnHand(Product_ID, Warehouse_ID, Locator_ID) - bomQtyReserved(Product_ID, Warehouse_ID, Locator_ID); +END; +$BODY$ +LANGUAGE 'plpgsql' STABLE +; + +CREATE OR REPLACE FUNCTION bomqtyonhand (in product_id numeric, in warehouse_id numeric, in locator_id numeric) RETURNS numeric AS +$BODY$ +DECLARE + myWarehouse_ID numeric; + v_Quantity numeric := 99999; -- unlimited + v_IsBOM CHAR(1); + v_IsStocked CHAR(1); + v_ProductType CHAR(1); + v_ProductQty numeric; + v_StdPrecision int; + bom record; + +BEGIN + -- Check Parameters + myWarehouse_ID := Warehouse_ID; + IF (myWarehouse_ID IS NULL) THEN + IF (Locator_ID IS NULL) THEN + RETURN 0; + ELSE + SELECT SUM(M_Warehouse_ID) INTO myWarehouse_ID + FROM M_LOCATOR + WHERE M_Locator_ID=Locator_ID; + END IF; + END IF; + IF (myWarehouse_ID IS NULL) THEN + RETURN 0; + END IF; + + -- Check, if product exists and if it is stocked + BEGIN + SELECT IsBOM, ProductType, IsStocked + INTO v_IsBOM, v_ProductType, v_IsStocked + FROM M_PRODUCT + WHERE M_Product_ID=Product_ID; + -- + EXCEPTION -- not found + WHEN OTHERS THEN + RETURN 0; + END; + -- Unimited capacity if no item + IF (v_IsBOM='N' AND (v_ProductType<>'I' OR v_IsStocked='N')) THEN + RETURN v_Quantity; + -- Stocked item + ELSIF (v_IsStocked='Y') THEN + -- Get ProductQty + SELECT COALESCE(SUM(QtyOnHand), 0) + INTO v_ProductQty + FROM M_STORAGE s + WHERE M_Product_ID=Product_ID + AND EXISTS (SELECT * FROM M_LOCATOR l WHERE s.M_Locator_ID=l.M_Locator_ID + AND l.M_Warehouse_ID=myWarehouse_ID); + -- + RETURN v_ProductQty; + END IF; + + -- Go though BOM + FOR bom IN -- Get BOM Product info + SELECT b.M_ProductBOM_ID, b.BOMQty, p.IsBOM, p.IsStocked, p.ProductType + FROM M_PRODUCT_BOM b, M_PRODUCT p + WHERE b.M_ProductBOM_ID=p.M_Product_ID + AND b.M_Product_ID=product_ID + AND b.M_ProductBOM_ID != Product_ID + AND p.IsBOM='Y' + AND p.IsVerified='Y' + AND b.IsActive='Y' + LOOP + -- Stocked Items "leaf node" + IF (bom.ProductType = 'I' AND bom.IsStocked = 'Y') THEN + -- Get v_ProductQty + SELECT COALESCE(SUM(QtyOnHand), 0) + INTO v_ProductQty + FROM M_STORAGE s + WHERE M_Product_ID=bom.M_ProductBOM_ID + AND EXISTS (SELECT * FROM M_LOCATOR l WHERE s.M_Locator_ID=l.M_Locator_ID + AND l.M_Warehouse_ID=myWarehouse_ID); + -- Get Rounding Precision + SELECT COALESCE(MAX(u.StdPrecision), 0) + INTO v_StdPrecision + FROM C_UOM u, M_PRODUCT p + WHERE u.C_UOM_ID=p.C_UOM_ID AND p.M_Product_ID=bom.M_ProductBOM_ID; + -- How much can we make with this product + v_ProductQty := ROUND (v_ProductQty/bom.BOMQty, v_StdPrecision); + -- How much can we make overall + IF (v_ProductQty < v_Quantity) THEN + v_Quantity := v_ProductQty; + END IF; + -- Another BOM + ELSIF (bom.IsBOM = 'Y') THEN + v_ProductQty := Bomqtyonhand (bom.M_ProductBOM_ID, myWarehouse_ID, Locator_ID); + -- How much can we make overall + IF (v_ProductQty < v_Quantity) THEN + v_Quantity := v_ProductQty; + END IF; + END IF; + END LOOP; -- BOM + + IF (v_Quantity > 0) THEN + -- Get Rounding Precision for Product + SELECT COALESCE(MAX(u.StdPrecision), 0) + INTO v_StdPrecision + FROM C_UOM u, M_PRODUCT p + WHERE u.C_UOM_ID=p.C_UOM_ID AND p.M_Product_ID=Product_ID; + -- + RETURN ROUND (v_Quantity, v_StdPrecision); + END IF; + RETURN 0; +END; +$BODY$ +LANGUAGE 'plpgsql' STABLE +; + +CREATE OR REPLACE FUNCTION bomqtyordered (in p_product_id numeric, in p_warehouse_id numeric, in p_locator_id numeric) RETURNS numeric AS +$BODY$ +DECLARE + v_Warehouse_ID numeric; + v_Quantity numeric := 99999; -- unlimited + v_IsBOM CHAR(1); + v_IsStocked CHAR(1); + v_ProductType CHAR(1); + v_ProductQty numeric; + v_StdPrecision int; + bom record; +BEGIN + -- Check Parameters + v_Warehouse_ID := p_Warehouse_ID; + IF (v_Warehouse_ID IS NULL) THEN + IF (p_Locator_ID IS NULL) THEN + RETURN 0; + ELSE + SELECT MAX(M_Warehouse_ID) INTO v_Warehouse_ID + FROM M_LOCATOR + WHERE M_Locator_ID=p_Locator_ID; + END IF; + END IF; + IF (v_Warehouse_ID IS NULL) THEN + RETURN 0; + END IF; + + -- Check, if product exists and if it is stocked + BEGIN + SELECT IsBOM, ProductType, IsStocked + INTO v_IsBOM, v_ProductType, v_IsStocked + FROM M_PRODUCT + WHERE M_Product_ID=p_Product_ID; + -- + EXCEPTION -- not found + WHEN OTHERS THEN + RETURN 0; + END; + + -- No reservation for non-stocked + IF (v_IsBOM='N' AND (v_ProductType<>'I' OR v_IsStocked='N')) THEN + RETURN 0; + -- Stocked item + ELSIF (v_IsStocked='Y') THEN + -- Get ProductQty + SELECT COALESCE(SUM(Qty), 0) + INTO v_ProductQty + FROM M_StorageReservation + WHERE M_Product_ID=p_Product_ID + AND M_Warehouse_ID=v_Warehouse_ID + AND IsSOTrx='N' + AND IsActive='Y'; + -- + RETURN v_ProductQty; + END IF; + + -- Go though BOM + FOR bom IN + -- Get BOM Product info + SELECT b.M_ProductBOM_ID, b.BOMQty, p.IsBOM, p.IsStocked, p.ProductType + FROM M_PRODUCT_BOM b, M_PRODUCT p + WHERE b.M_ProductBOM_ID=p.M_Product_ID + AND b.M_Product_ID=p_Product_ID + AND b.M_ProductBOM_ID != p_Product_ID + AND p.IsBOM='Y' + AND p.IsVerified='Y' + AND b.IsActive='Y' + LOOP + -- Stocked Items "leaf node" + IF (bom.ProductType = 'I' AND bom.IsStocked = 'Y') THEN + -- Get ProductQty + SELECT COALESCE(SUM(Qty), 0) + INTO v_ProductQty + FROM M_StorageReservation + WHERE M_Product_ID=p_Product_ID + AND M_Warehouse_ID=v_Warehouse_ID + AND IsSOTrx='N' + AND IsActive='Y'; + -- Get Rounding Precision + SELECT COALESCE(MAX(u.StdPrecision), 0) + INTO v_StdPrecision + FROM C_UOM u, M_PRODUCT p + WHERE u.C_UOM_ID=p.C_UOM_ID AND p.M_Product_ID=bom.M_ProductBOM_ID; + -- How much can we make with this product + v_ProductQty := ROUND (v_ProductQty/bom.BOMQty, v_StdPrecision ); + + -- How much can we make overall + IF (v_ProductQty < v_Quantity) THEN + v_Quantity := v_ProductQty; + END IF; + -- Another BOM + ELSIF (bom.IsBOM = 'Y') THEN + v_ProductQty := Bomqtyordered (bom.M_ProductBOM_ID, v_Warehouse_ID, p_Locator_ID); + -- How much can we make overall + IF (v_ProductQty < v_Quantity) THEN + v_Quantity := v_ProductQty; + END IF; + END IF; + END LOOP; -- BOM + + -- Unlimited (e.g. only services) + IF (v_Quantity = 99999) THEN + RETURN 0; + END IF; + + IF (v_Quantity > 0) THEN + -- Get Rounding Precision for Product + SELECT COALESCE(MAX(u.StdPrecision), 0) + INTO v_StdPrecision + FROM C_UOM u, M_PRODUCT p + WHERE u.C_UOM_ID=p.C_UOM_ID AND p.M_Product_ID=p_Product_ID; + -- + RETURN ROUND (v_Quantity, v_StdPrecision ); + END IF; + -- + RETURN 0; +END; +$BODY$ + LANGUAGE plpgsql STABLE; + +CREATE OR REPLACE FUNCTION bomqtyreserved (in p_product_id numeric, in p_warehouse_id numeric, in p_locator_id numeric) RETURNS numeric AS +$BODY$ +DECLARE + v_Warehouse_ID numeric; + v_Quantity numeric := 99999; -- unlimited + v_IsBOM CHAR(1); + v_IsStocked CHAR(1); + v_ProductType CHAR(1); + v_ProductQty numeric; + v_StdPrecision int; + bom record; +BEGIN + -- Check Parameters + v_Warehouse_ID := p_Warehouse_ID; + IF (v_Warehouse_ID IS NULL) THEN + IF (p_Locator_ID IS NULL) THEN + RETURN 0; + ELSE + SELECT MAX(M_Warehouse_ID) INTO v_Warehouse_ID + FROM M_LOCATOR + WHERE M_Locator_ID=p_Locator_ID; + END IF; + END IF; + IF (v_Warehouse_ID IS NULL) THEN + RETURN 0; + END IF; + + -- Check, if product exists and if it is stocked + BEGIN + SELECT IsBOM, ProductType, IsStocked + INTO v_IsBOM, v_ProductType, v_IsStocked + FROM M_PRODUCT + WHERE M_Product_ID=p_Product_ID; + -- + EXCEPTION -- not found + WHEN OTHERS THEN + RETURN 0; + END; + + -- No reservation for non-stocked + IF (v_IsBOM='N' AND (v_ProductType<>'I' OR v_IsStocked='N')) THEN + RETURN 0; + -- Stocked item + ELSIF (v_IsStocked='Y') THEN + -- Get ProductQty + SELECT COALESCE(SUM(Qty), 0) + INTO v_ProductQty + FROM M_StorageReservation + WHERE M_Product_ID=p_Product_ID + AND M_Warehouse_ID=v_Warehouse_ID + AND IsSOTrx='Y' + AND IsActive='Y'; + -- + RETURN v_ProductQty; + END IF; + + -- Go though BOM + FOR bom IN + -- Get BOM Product info + SELECT b.M_ProductBOM_ID, b.BOMQty, p.IsBOM, p.IsStocked, p.ProductType + FROM M_PRODUCT_BOM b, M_PRODUCT p + WHERE b.M_ProductBOM_ID=p.M_Product_ID + AND b.M_Product_ID=p_Product_ID + AND b.M_ProductBOM_ID != p_Product_ID + AND p.IsBOM='Y' + AND p.IsVerified='Y' + AND b.IsActive='Y' + LOOP + -- Stocked Items "leaf node" + IF (bom.ProductType = 'I' AND bom.IsStocked = 'Y') THEN + -- Get ProductQty + SELECT COALESCE(SUM(Qty), 0) + INTO v_ProductQty + FROM M_StorageReservation + WHERE M_Product_ID=bom.M_ProductBOM_ID + AND M_Warehouse_ID =v_Warehouse_ID + AND IsSOTrx='Y' + AND IsActive='Y'; + -- Get Rounding Precision + SELECT COALESCE(MAX(u.StdPrecision), 0) + INTO v_StdPrecision + FROM C_UOM u, M_PRODUCT p + WHERE u.C_UOM_ID=p.C_UOM_ID AND p.M_Product_ID=bom.M_ProductBOM_ID; + -- How much can we make with this product + v_ProductQty := ROUND (v_ProductQty/bom.BOMQty, v_StdPrecision); + -- How much can we make overall + IF (v_ProductQty < v_Quantity) THEN + v_Quantity := v_ProductQty; + END IF; + -- Another BOM + ELSIF (bom.IsBOM = 'Y') THEN + v_ProductQty := Bomqtyreserved (bom.M_ProductBOM_ID, v_Warehouse_ID, p_Locator_ID); + -- How much can we make overall + IF (v_ProductQty < v_Quantity) THEN + v_Quantity := v_ProductQty; + END IF; + END IF; + END LOOP; -- BOM + + -- Unlimited (e.g. only services) + IF (v_Quantity = 99999) THEN + RETURN 0; + END IF; + + IF (v_Quantity > 0) THEN + -- Get Rounding Precision for Product + SELECT COALESCE(MAX(u.StdPrecision), 0) + INTO v_StdPrecision + FROM C_UOM u, M_PRODUCT p + WHERE u.C_UOM_ID=p.C_UOM_ID AND p.M_Product_ID=p_Product_ID; + -- + RETURN ROUND (v_Quantity, v_StdPrecision); + END IF; + RETURN 0; +END; +$BODY$ + LANGUAGE plpgsql STABLE; + + +SELECT register_migration_script('201405160521_IDEMPIERE-1953.sql') FROM dual +; \ No newline at end of file diff --git a/org.adempiere.base/src/org/compiere/acct/Doc_Invoice.java b/org.adempiere.base/src/org/compiere/acct/Doc_Invoice.java index 1f0c6368c5..61f3dd94f6 100644 --- a/org.adempiere.base/src/org/compiere/acct/Doc_Invoice.java +++ b/org.adempiere.base/src/org/compiere/acct/Doc_Invoice.java @@ -22,6 +22,8 @@ import java.sql.ResultSet; import java.sql.SQLException; import java.sql.Savepoint; import java.util.ArrayList; +import java.util.HashMap; +import java.util.Map; import java.util.logging.Level; import org.adempiere.exceptions.AverageCostingZeroQtyException; @@ -826,6 +828,8 @@ public class Doc_Invoice extends Doc for (int i = 0; i < lcas.length; i++) totalBase += lcas[i].getBase().doubleValue(); + Map costDetailAmtMap = new HashMap(); + // Create New MInvoiceLine il = new MInvoiceLine (getCtx(), C_InvoiceLine_ID, getTrxName()); for (int i = 0; i < lcas.length; i++) @@ -878,11 +882,11 @@ public class Doc_Invoice extends Doc if (estimatedAmt.scale() > as.getCostingPrecision()) { - estimatedAmt.setScale(as.getCostingPrecision(), BigDecimal.ROUND_HALF_UP); + estimatedAmt = estimatedAmt.setScale(as.getCostingPrecision(), BigDecimal.ROUND_HALF_UP); } BigDecimal costAdjustmentAmt = allocationAmt; if (estimatedAmt.signum() > 0) - { + { //get other allocation amt StringBuilder sql = new StringBuilder("SELECT Sum(Amt) FROM C_LandedCostAllocation WHERE M_InOutLine_ID=? ") .append("AND C_LandedCostAllocation_ID<>? ") @@ -900,7 +904,7 @@ public class Doc_Invoice extends Doc } } if (estimatedAmt.signum() > 0) - { + { if (allocationAmt.signum() > 0) costAdjustmentAmt = allocationAmt.subtract(estimatedAmt); else if (allocationAmt.signum() < 0) @@ -928,6 +932,12 @@ public class Doc_Invoice extends Doc if (costDetailAmt.scale() > as.getCostingPrecision()) costDetailAmt = costDetailAmt.setScale(as.getCostingPrecision(), BigDecimal.ROUND_HALF_UP); + String key = lca.getM_Product_ID()+"_"+lca.getM_AttributeSetInstance_ID(); + BigDecimal prevAmt = costDetailAmtMap.remove(key); + if (prevAmt != null) { + costDetailAmt = costDetailAmt.add(prevAmt); + } + costDetailAmtMap.put(key, costDetailAmt); if (!MCostDetail.createInvoice(as, lca.getAD_Org_ID(), lca.getM_Product_ID(), lca.getM_AttributeSetInstance_ID(), C_InvoiceLine_ID, lca.getM_CostElement_ID(), @@ -963,6 +973,14 @@ public class Doc_Invoice extends Doc if (allocationAmt.signum() > 0) { + if (allocationAmt.scale() > as.getStdPrecision()) + { + allocationAmt = allocationAmt.setScale(as.getStdPrecision(), BigDecimal.ROUND_HALF_UP); + } + if (estimatedAmt.scale() > as.getStdPrecision()) + { + estimatedAmt = estimatedAmt.setScale(as.getStdPrecision(), BigDecimal.ROUND_HALF_UP); + } int compare = allocationAmt.compareTo(estimatedAmt); if (compare > 0) { diff --git a/org.adempiere.base/src/org/compiere/model/MCost.java b/org.adempiere.base/src/org/compiere/model/MCost.java index b67fcbe2b0..b9dd42fe44 100644 --- a/org.adempiere.base/src/org/compiere/model/MCost.java +++ b/org.adempiere.base/src/org/compiere/model/MCost.java @@ -1500,14 +1500,18 @@ public class MCost extends X_M_Cost throw new AverageCostingNegativeQtyException("Product(ID)="+getM_Product_ID()+", Current Qty="+getCurrentQty()+", Trx Qty="+qty +", CostElement="+getM_CostElement().getName()+", Schema="+getC_AcctSchema().getName()); } - - BigDecimal oldSum = getCurrentCostPrice().multiply(getCurrentQty()); - BigDecimal newSum = amt; // is total already - BigDecimal sumAmt = oldSum.add(newSum); + BigDecimal sumQty = getCurrentQty().add(qty); if (sumQty.signum() != 0) { - BigDecimal cost = sumAmt.divide(sumQty, getPrecision(), BigDecimal.ROUND_HALF_UP); + BigDecimal oldSum = getCurrentCostPrice().multiply(getCurrentQty()); + BigDecimal oldCost = oldSum.divide(sumQty, 12, BigDecimal.ROUND_HALF_UP); + BigDecimal newCost = amt.divide(sumQty, 12, BigDecimal.ROUND_HALF_UP); //amt is total already + BigDecimal cost = oldCost.add(newCost); + if (cost.scale() > (getPrecision()*2)) + { + cost = cost.setScale((getPrecision()*2), BigDecimal.ROUND_HALF_UP); + } setCurrentCostPrice(cost); } // diff --git a/org.adempiere.base/src/org/compiere/model/MInvoiceLine.java b/org.adempiere.base/src/org/compiere/model/MInvoiceLine.java index ca1376503d..efea41e29e 100644 --- a/org.adempiere.base/src/org/compiere/model/MInvoiceLine.java +++ b/org.adempiere.base/src/org/compiere/model/MInvoiceLine.java @@ -1119,6 +1119,16 @@ public class MInvoiceLine extends X_C_InvoiceLine MLandedCostAllocation lca = new MLandedCostAllocation (this, lc.getM_CostElement_ID()); lca.setM_Product_ID(lc.getM_Product_ID()); // No ASI lca.setAmt(getLineNetAmt()); + if (lc.getLandedCostDistribution().equals(MLandedCost.LANDEDCOSTDISTRIBUTION_Costs)) + { + lca.setBase(getLineNetAmt()); + lca.setQty(getLineNetAmt()); + } + else + { + lca.setBase(getQtyInvoiced()); + lca.setQty(getQtyInvoiced()); + } if (lca.save()) return ""; msgreturn = new StringBuilder("Cannot save Product Allocation = ").append(lc); diff --git a/org.adempiere.base/src/org/compiere/print/layout/TableElement.java b/org.adempiere.base/src/org/compiere/print/layout/TableElement.java index abb58e8d1b..92ac9f3c2b 100644 --- a/org.adempiere.base/src/org/compiere/print/layout/TableElement.java +++ b/org.adempiere.base/src/org/compiere/print/layout/TableElement.java @@ -1226,8 +1226,8 @@ public class TableElement extends PrintElement int startX = (int)pageStart.getX(); int startY = (int)pageStart.getY(); // Table Start - startX += pageXindex == 0 ? m_firstPage.x : m_nextPages.x; - startY += pageYindex == 0 ? m_firstPage.y : m_nextPages.y; + startX += pageIndex == 0 ? m_firstPage.x : m_nextPages.x; + startY += pageIndex == 0 ? m_firstPage.y : m_nextPages.y; if (DEBUG_PRINT) if (log.isLoggable(Level.FINEST)) log.finest("PageStart=" + pageStart + ", StartTable x=" + startX + ", y=" + startY); diff --git a/org.adempiere.ui.zk/WEB-INF/src/org/adempiere/webui/panel/InfoPanel.java b/org.adempiere.ui.zk/WEB-INF/src/org/adempiere/webui/panel/InfoPanel.java index 25b6a9c196..7b273e0a23 100644 --- a/org.adempiere.ui.zk/WEB-INF/src/org/adempiere/webui/panel/InfoPanel.java +++ b/org.adempiere.ui.zk/WEB-INF/src/org/adempiere/webui/panel/InfoPanel.java @@ -337,7 +337,7 @@ public abstract class InfoPanel extends Window implements EventListener, // m_sqlOrder = ""; // m_sqlUserOrder = ""; - if (orderBy != null && orderBy.length() > 0) + if (orderBy != null && orderBy.trim().length() > 0) m_sqlOrder = " ORDER BY " + orderBy; } // prepareTable