diff --git a/db/oracle/functions/BOM_PriceLimit.sql b/db/oracle/functions/BOM_PriceLimit.sql index 8ca102b31c..dc32f5912d 100644 --- a/db/oracle/functions/BOM_PriceLimit.sql +++ b/db/oracle/functions/BOM_PriceLimit.sql @@ -27,6 +27,7 @@ AS 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.IsVerified='Y' AND b.IsActive='Y'; -- BEGIN diff --git a/db/oracle/functions/BOM_PriceList.sql b/db/oracle/functions/BOM_PriceList.sql index b9590f4501..a8e2c3d64f 100644 --- a/db/oracle/functions/BOM_PriceList.sql +++ b/db/oracle/functions/BOM_PriceList.sql @@ -27,6 +27,7 @@ AS 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.IsVerified='Y' AND b.IsActive='Y'; -- BEGIN diff --git a/db/oracle/functions/BOM_PriceStd.sql b/db/oracle/functions/BOM_PriceStd.sql index 143dbf87d6..6501cc8187 100644 --- a/db/oracle/functions/BOM_PriceStd.sql +++ b/db/oracle/functions/BOM_PriceStd.sql @@ -27,6 +27,7 @@ AS 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.IsVerified='Y' AND b.IsActive='Y'; -- BEGIN diff --git a/db/postgresql/functions/BOM_PriceLimit.sql b/db/postgresql/functions/BOM_PriceLimit.sql index 216dce20a5..f06200dcb4 100644 --- a/db/postgresql/functions/BOM_PriceLimit.sql +++ b/db/postgresql/functions/BOM_PriceLimit.sql @@ -20,6 +20,7 @@ BEGIN 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.IsVerified='Y' AND b.IsActive='Y' LOOP v_ProductPrice := bomPriceLimit (bom.M_ProductBOM_ID, PriceList_Version_ID); diff --git a/db/postgresql/functions/BOM_PriceList.sql b/db/postgresql/functions/BOM_PriceList.sql index 03f69e0dae..4f81e25bde 100644 --- a/db/postgresql/functions/BOM_PriceList.sql +++ b/db/postgresql/functions/BOM_PriceList.sql @@ -20,6 +20,7 @@ BEGIN 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.IsVerified='Y' AND b.IsActive='Y' LOOP v_ProductPrice := bomPriceList (bom.M_ProductBOM_ID, PriceList_Version_ID); diff --git a/db/postgresql/functions/BOM_PriceStd.sql b/db/postgresql/functions/BOM_PriceStd.sql index 5c34e42dca..fbfc35e194 100644 --- a/db/postgresql/functions/BOM_PriceStd.sql +++ b/db/postgresql/functions/BOM_PriceStd.sql @@ -20,6 +20,7 @@ BEGIN 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.IsVerified='Y' AND b.IsActive='Y' LOOP v_ProductPrice := bomPriceStd (bom.M_ProductBOM_ID, PriceList_Version_ID); diff --git a/migration/iD11/oracle/202406072206_IDEMPIERE-6167.sql b/migration/iD11/oracle/202406072206_IDEMPIERE-6167.sql new file mode 100644 index 0000000000..52857fe3e4 --- /dev/null +++ b/migration/iD11/oracle/202406072206_IDEMPIERE-6167.sql @@ -0,0 +1,161 @@ +-- IDEMPIERE-6167 BOM Price List must search just for Verified BOMs +SELECT register_migration_script('202406072206_IDEMPIERE-6167.sql') FROM dual; + +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.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.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.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; +/ + diff --git a/migration/iD11/postgresql/202406072206_IDEMPIERE-6167.sql b/migration/iD11/postgresql/202406072206_IDEMPIERE-6167.sql new file mode 100644 index 0000000000..74210abf71 --- /dev/null +++ b/migration/iD11/postgresql/202406072206_IDEMPIERE-6167.sql @@ -0,0 +1,117 @@ +-- IDEMPIERE-6167 BOM Price List must search just for Verified BOMs +SELECT register_migration_script('202406072206_IDEMPIERE-6167.sql') FROM dual; + +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.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.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.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 +; +