diff --git a/migration/352a-trunk/postgresql/315_replace_pljava_for34.sql b/migration/352a-trunk/postgresql/315_replace_pljava_for34.sql index e0d4dd3001..d32d9153f7 100644 --- a/migration/352a-trunk/postgresql/315_replace_pljava_for34.sql +++ b/migration/352a-trunk/postgresql/315_replace_pljava_for34.sql @@ -58,1084 +58,499 @@ $body$ LANGUAGE plpgsql; -/* - *This file is part of Adempiere ERP Bazaar - *http://www.adempiere.org - * - *Copyright (C) 2006-2008 Antonio Cañaveral, e-Evolution - * - *This program is free software; you can redistribute it and/or - *modify it under the terms of the GNU General Public License - *as published by the Free Software Foundation; either version 2 - *of the License, or (at your option) any later version. - * - *This program is distributed in the hope that it will be useful, - *but WITHOUT ANY WARRANTY; without even the implied warranty of - *MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the - *GNU General Public License for more details. - * - *You should have received a copy of the GNU General Public License - *along with this program; if not, write to the Free Software - *Foundation, Inc., 51 Franklin Street, Fifth Floor, Boston, MA 02110-1301, USA.of - */ -CREATE OR REPLACE FUNCTION bompricelimit(p_product_id numeric, p_pricelist_version_id numeric) - RETURNS numeric AS -$BODY$ +CREATE OR REPLACE FUNCTION bompricelimit(Product_id numeric, Pricelist_version_id numeric) RETURNS numeric AS $bompricelimit$ DECLARE - v_Price numeric; - v_ProductPrice numeric; - bom record; + 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=p_PriceList_Version_ID AND M_Product_ID=p_Product_ID; + 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 bl.M_Product_ID AS M_ProductBOM_ID, - CASE WHEN bl.IsQtyPercentage = 'N' THEN bl.QtyBOM ELSE bl.QtyBatch / 100 END AS BomQty , p.IsBOM - FROM PP_PRODUCT_BOM b - INNER JOIN M_PRODUCT p ON (p.M_Product_ID=b.M_Product_ID) - INNER JOIN PP_PRODUCT_BOMLINE bl ON (bl.PP_Product_BOM_ID=b.PP_Product_BOM_ID) - WHERE b.M_Product_ID = p_Product_ID + 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 LOOP - v_ProductPrice := Bompricelimit (bom.M_ProductBOM_ID, p_PriceList_Version_ID); + 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' ; + +$bompricelimit$ LANGUAGE plpgsql; + + + + +ALTER FUNCTION bompricelimit(m_product_id numeric, m_pricelist_version_id numeric) OWNER TO adempiere; -/* - *This file is part of Adempiere ERP Bazaar - *http://www.adempiere.org - *Copyright (C) 2006-2008 victor.perez@e-evolution.com, e-Evolution - *This program is free software; you can redistribute it and/or - *modify it under the terms of the GNU General Public License - *as published by the Free Software Foundation; either version 2 - *of the License, or (at your option) any later version. - * - *This program is distributed in the hope that it will be useful, - *but WITHOUT ANY WARRANTY; without even the implied warranty of - *MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the - *GNU General Public License for more details. - * - *You should have received a copy of the GNU General Public License - *along with this program; if not, write to the Free Software - *Foundation, Inc., 51 Franklin Street, Fifth Floor, Boston, MA 02110-1301, USA.of - * Title: Return List Price of Product/BOM - * Description: - */ -CREATE OR REPLACE FUNCTION Bompricelist -( - Product_ID numeric, - PriceList_Version_ID numeric -) -RETURNS numeric -AS -$BODY$ +CREATE OR REPLACE FUNCTION bompricelist(Product_id numeric, Pricelist_version_id numeric) RETURNS numeric AS $bompricelist$ DECLARE - v_Price numeric; - v_ProductPrice numeric; - bom record; + 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 + 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 - --Get BOM Product info - SELECT bl.M_Product_ID AS M_ProductBOM_ID, CASE WHEN bl.IsQtyPercentage = 'N' THEN bl.QtyBOM ELSE bl.QtyBatch / 100 END AS BomQty , p.IsBOM - FROM PP_PRODUCT_BOM b - INNER JOIN M_PRODUCT p ON (p.M_Product_ID=b.M_Product_ID) - INNER JOIN PP_PRODUCT_BOMLINE bl ON (bl.PP_Product_BOM_ID=b.PP_Product_BOM_ID) - WHERE b.M_Product_ID = Product_ID + 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 LOOP - v_ProductPrice := Bompricelist (bom.M_ProductBOM_ID, PriceList_Version_ID); + 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 LOOP; END IF; -- RETURN v_Price; + END; -$BODY$ - LANGUAGE 'plpgsql' ; +$bompricelist$ LANGUAGE plpgsql; + + +ALTER FUNCTION bompricelist(m_product_id numeric, m_pricelist_version_id numeric) OWNER TO adempiere; -/* - *This file is part of Adempiere ERP Bazaar - *http://www.adempiere.org - *Copyright (C) 2006-2008 victor.perez@e-evolution.com, e-Evolution - *This program is free software; you can redistribute it and/or - *modify it under the terms of the GNU General Public License - *as published by the Free Software Foundation; either version 2 - *of the License, or (at your option) any later version. - * - *This program is distributed in the hope that it will be useful, - *but WITHOUT ANY WARRANTY; without even the implied warranty of - *MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the - *GNU General Public License for more details. - * - *You should have received a copy of the GNU General Public License - *along with this program; if not, write to the Free Software - *Foundation, Inc., 51 Franklin Street, Fifth Floor, Boston, MA 02110-1301, USA.of - * Title: Return Standard Price of Product/BOM - * Description: - */ -CREATE OR REPLACE FUNCTION Bompricestd -( - Product_ID numeric, - PriceList_Version_ID numeric -) -RETURNS numeric -AS -$BODY$ +CREATE OR REPLACE FUNCTION bompricestd(Product_id numeric, Pricelist_version_id numeric) RETURNS numeric AS $bompricestd$ DECLARE - v_Price numeric; - v_ProductPrice numeric; - bom record; + v_Price NUMERIC; + v_ProductPrice NUMERIC; + bom RECORD; + BEGIN - -- Try to get price from pricelist directly + -- Try to get price from PriceList directly SELECT COALESCE(SUM(PriceStd), 0) INTO v_Price - FROM M_PRODUCTPRICE + 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 -- Get BOM Product info - SELECT bl.M_Product_ID AS M_ProductBOM_ID, CASE WHEN bl.IsQtyPercentage = 'N' THEN bl.QtyBOM ELSE bl.QtyBatch / 100 END AS BomQty , p.IsBOM - FROM PP_PRODUCT_BOM b - INNER JOIN M_PRODUCT p ON (p.M_Product_ID=b.M_Product_ID) - INNER JOIN PP_PRODUCT_BOMLINE bl ON (bl.PP_Product_BOM_ID=b.PP_Product_BOM_ID) - WHERE b.M_Product_ID = Product_ID + 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 LOOP - v_ProductPrice := Bompricestd (bom.M_ProductBOM_ID, PriceList_Version_ID); + 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 LOOP; END IF; -- RETURN v_Price; -END; -$BODY$ - LANGUAGE 'plpgsql' ; - - -/* - *This file is part of Adempiere ERP Bazaar - *http://www.adempiere.org - *Copyright (C) 2006-2008 victor.perez@e-evolution.com, e-Evolution - *This program is free software; you can redistribute it and/or - *modify it under the terms of the GNU General Public License - *as published by the Free Software Foundation; either version 2 - *of the License, or (at your option) any later version. - * - *This program is distributed in the hope that it will be useful, - *but WITHOUT ANY WARRANTY; without even the implied warranty of - *MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the - *GNU General Public License for more details. - * - *You should have received a copy of the GNU General Public License - *along with this program; if not, write to the Free Software - *Foundation, Inc., 51 Franklin Street, Fifth Floor, Boston, MA 02110-1301, USA.of - */ -CREATE OR REPLACE FUNCTION bomQtyAvailable(Product_ID numeric, Warehouse_ID numeric ,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' ; - -/* - *This file is part of Adempiere ERP Bazaar - *http://www.adempiere.org - *Copyright (C) 2006-2008 carlos.ruiz@globalqss.com, GlobalQSS - *This program is free software; you can redistribute it and/or - *modify it under the terms of the GNU General Public License - *as published by the Free Software Foundation; either version 2 - *of the License, or (at your option) any later version. - * - *This program is distributed in the hope that it will be useful, - *but WITHOUT ANY WARRANTY; without even the implied warranty of - *MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the - *GNU General Public License for more details. - * - *You should have received a copy of the GNU General Public License - *along with this program; if not, write to the Free Software - *Foundation, Inc., 51 Franklin Street, Fifth Floor, Boston, MA 02110-1301, USA.of - */ -CREATE OR REPLACE FUNCTION bomQtyAvailableASI(Product_ID numeric, AttributeSetInstance_ID numeric, Warehouse_ID numeric ,Locator_ID numeric) - RETURNS numeric AS -$BODY$ -BEGIN - RETURN bomQtyOnHandASI(Product_ID, AttributeSetInstance_ID, Warehouse_ID, Locator_ID) - - bomQtyReservedASI(Product_ID, AttributeSetInstance_ID, Warehouse_ID, Locator_ID); -END; -$BODY$ - LANGUAGE 'plpgsql' ; - - -/* - *This file is part of Adempiere ERP Bazaar - *http://www.adempiere.org - *Copyright (C) 2006-2008 victor.perez@e-evolution.com, e-Evolution - *This program is free software; you can redistribute it and/or - *modify it under the terms of the GNU General Public License - *as published by the Free Software Foundation; either version 2 - *of the License, or (at your option) any later version. - * - *This program is distributed in the hope that it will be useful, - *but WITHOUT ANY WARRANTY; without even the implied warranty of - *MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the - *GNU General Public License for more details. - * - *You should have received a copy of the GNU General Public License - *along with this program; if not, write to the Free Software - *Foundation, Inc., 51 Franklin Street, Fifth Floor, Boston, MA 02110-1301, USA.of - */ -CREATE OR REPLACE FUNCTION Bomqtyonhand -( - Product_ID numeric, - Warehouse_ID numeric, - Locator_ID numeric -- Only used, if warehouse is null -) -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; --- DBMS_OUTPUT.PUT_LINE('Warehouse=' || myWarehouse_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=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); - -- - -- 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 bl.M_Product_ID AS M_ProductBOM_ID, CASE WHEN bl.IsQtyPercentage = 'N' THEN bl.QtyBOM ELSE bl.QtyBatch / 100 END AS BomQty , p.IsBOM , p.IsStocked, p.ProductType - FROM PP_PRODUCT_BOM b - INNER JOIN M_PRODUCT p ON (p.M_Product_ID=b.M_Product_ID) - INNER JOIN PP_PRODUCT_BOMLINE bl ON (bl.PP_Product_BOM_ID=b.PP_Product_BOM_ID) - WHERE b.M_Product_ID = Product_ID - 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' ; -/* - *This file is part of Adempiere ERP Bazaar - *http://www.adempiere.org - *Copyright (C) 2006-2008 victor.perez@e-evolution.com, e-Evolution - *This program is free software; you can redistribute it and/or - *modify it under the terms of the GNU General Public License - *as published by the Free Software Foundation; either version 2 - *of the License, or (at your option) any later version. - * - *This program is distributed in the hope that it will be useful, - *but WITHOUT ANY WARRANTY; without even the implied warranty of - *MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the - *GNU General Public License for more details. - * - *You should have received a copy of the GNU General Public License - *along with this program; if not, write to the Free Software - *Foundation, Inc., 51 Franklin Street, Fifth Floor, Boston, MA 02110-1301, USA.of - * Return quantity on hand for BOM ASI - */ -CREATE OR REPLACE FUNCTION BomqtyonhandASI -( - Product_ID numeric, - AttributeSetInstance_ID numeric, - Warehouse_ID numeric, - Locator_ID numeric -- Only used, if warehouse is null -) -RETURNS numeric -AS -$BODY$ +$bompricestd$ LANGUAGE plpgsql; + +ALTER FUNCTION bompricestd(m_product_id numeric, m_pricelist_version_id numeric) OWNER TO adempiere; + +CREATE OR REPLACE FUNCTION bomqtyavailable(Product_ID numeric, Attributesetinstance_id numeric, Warehouse_ID numeric, Locator_ID numeric) + RETURNS numeric AS $bomqtyavailable$ + +BEGIN + + RETURN bomQtyOnHand(Product_ID, Attributesetinstance_id, Warehouse_ID, Locator_ID) + - bomQtyReserved(Product_ID, Attributesetinstance_id, Warehouse_ID, Locator_ID); + +END; + +$bomqtyavailable$ LANGUAGE plpgsql; + +CREATE OR REPLACE FUNCTION bomqtyavailable(Product_id numeric, Warehouse_id numeric, Locator_id numeric) + RETURNS numeric AS $bomqtyavailable$ DECLARE - myWarehouse_ID numeric; - v_Quantity numeric := 99999; -- unlimited + v_Price NUMERIC; + v_ProductPrice NUMERIC; + bom RECORD; + +BEGIN + + RETURN bomQtyOnHand(Product_ID, Warehouse_ID, Locator_ID) + - bomQtyReserved(Product_ID, Warehouse_ID, Locator_ID); + +END; + +$bomqtyavailable$ LANGUAGE plpgsql; + + +CREATE OR REPLACE FUNCTION bomqtyonhand(p_Product_ID numeric, p_Warehouse_ID numeric, p_Locator_ID numeric) + RETURNS numeric AS $bomqtyonhand$ +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 numeric; - bom record; + v_ProductQty NUMERIC; + v_StdPrecision NUMERIC; + 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; + 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; - 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 v_IsBOM, v_ProductType, v_IsStocked - FROM M_PRODUCT - WHERE M_Product_ID=Product_ID; - -- - EXCEPTION -- not found - WHEN OTHERS THEN + IF (v_Warehouse_ID IS NULL) 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 v_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) - AND (s.M_AttributeSetInstance_ID = AttributeSetInstance_ID OR COALESCE(AttributeSetInstance_ID,0) = 0); - -- - -- 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 bl.M_Product_ID AS M_ProductBOM_ID, CASE WHEN bl.IsQtyPercentage = 'N' THEN bl.QtyBOM ELSE bl.QtyBatch / 100 END AS BomQty , p.IsBOM , p.IsStocked, p.ProductType - FROM PP_PRODUCT_BOM b - INNER JOIN M_PRODUCT p ON (p.M_Product_ID=b.M_Product_ID) - INNER JOIN PP_PRODUCT_BOMLINE bl ON (bl.PP_Product_BOM_ID=b.PP_Product_BOM_ID) - WHERE b.M_Product_ID = Product_ID - LOOP - -- Stocked Items "leaf node" - IF (bom.ProductType = 'I' AND bom.IsStocked = 'Y') THEN - -- Get v_ProductQty + 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 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) - AND (s.M_AttributeSetInstance_ID = AttributeSetInstance_ID OR COALESCE(AttributeSetInstance_ID,0) = 0); - -- Get Rounding Precision + FROM M_Storage s + WHERE M_Product_ID=p_Product_ID + AND EXISTS (SELECT * FROM M_Locator l WHERE s.M_Locator_ID=l.M_Locator_ID + AND l.M_Warehouse_ID=v_Warehouse_ID); + -- + RETURN v_ProductQty; + END IF; + + -- Go though BOM + + FOR bom IN + 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 + LOOP + -- Stocked Items "leaf node" + IF (bom.ProductType = 'I' AND bom.IsStocked = 'Y') THEN + -- Get 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=v_Warehouse_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, 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 + + + 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=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 := BomqtyonhandASI (bom.M_ProductBOM_ID, AttributeSetInstance_ID, myWarehouse_ID, Locator_ID); - -- How much can we make overall - IF (v_ProductQty < v_Quantity) THEN - v_Quantity := v_ProductQty; - END IF; + 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; - 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' ; -/* - *This file is part of Adempiere ERP Bazaar - *http://www.adempiere.org - *Copyright (C) 2006-2008 victor.perez@e-evolution.com, e-Evolution - *This program is free software; you can redistribute it and/or - *modify it under the terms of the GNU General Public License - *as published by the Free Software Foundation; either version 2 - *of the License, or (at your option) any later version. - * - *This program is distributed in the hope that it will be useful, - *but WITHOUT ANY WARRANTY; without even the implied warranty of - *MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the - *GNU General Public License for more details. - * - *You should have received a copy of the GNU General Public License - *along with this program; if not, write to the Free Software - *Foundation, Inc., 51 Franklin Street, Fifth Floor, Boston, MA 02110-1301, USA.of - * Return quantity ordered for BOM - */ -CREATE OR REPLACE FUNCTION Bomqtyordered -( - p_Product_ID numeric, - p_Warehouse_ID numeric, - p_Locator_ID numeric -- Only used, if warehouse is null -) -RETURNS numeric -AS -$BODY$ +$bomqtyonhand$ LANGUAGE plpgsql; + + + +-- ?? CREATE OR REPLACE FUNCTION BomqtyonhandASI + +CREATE OR REPLACE FUNCTION bomqtyordered(p_Product_ID numeric, p_Warehouse_ID numeric, p_Locator_ID numeric) + RETURNS numeric AS $bomqtyordered$ DECLARE - v_Warehouse_ID numeric; - v_Quantity numeric := 99999; -- unlimited + 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; + v_ProductQty NUMERIC; + v_StdPrecision NUMERIC; + 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; + 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; - 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 + IF (v_Warehouse_ID IS NULL) 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(QtyOrdered), 0) - INTO v_ProductQty - FROM M_STORAGE s - WHERE M_Product_ID=p_Product_ID - AND EXISTS (SELECT * FROM M_LOCATOR l WHERE s.M_Locator_ID=l.M_Locator_ID - AND l.M_Warehouse_ID=v_Warehouse_ID); - -- - RETURN v_ProductQty; - END IF; - - -- Go though BOM --- DBMS_OUTPUT.PUT_LINE('BOM'); - FOR bom IN - -- Get BOM Product info - SELECT bl.M_Product_ID AS M_ProductBOM_ID, CASE WHEN bl.IsQtyPercentage = 'N' THEN bl.QtyBOM ELSE bl.QtyBatch / 100 END AS BomQty , p.IsBOM , p.IsStocked, p.ProductType - FROM PP_PRODUCT_BOM b - INNER JOIN M_PRODUCT p ON (p.M_Product_ID=b.M_Product_ID) - INNER JOIN PP_PRODUCT_BOMLINE bl ON (bl.PP_Product_BOM_ID=b.PP_Product_BOM_ID) - WHERE b.M_Product_ID = p_Product_ID - LOOP - -- Stocked Items "leaf node" - IF (bom.ProductType = 'I' AND bom.IsStocked = 'Y') THEN + 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 COALESCE(SUM(QtyOrdered), 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 + FROM M_Storage s + WHERE M_Product_ID=p_Product_ID + AND EXISTS (SELECT * FROM M_Locator l WHERE s.M_Locator_ID=l.M_Locator_ID AND l.M_Warehouse_ID=v_Warehouse_ID); - -- Get Rounding Precision + -- + RETURN v_ProductQty; + END IF; + + -- Go though BOM + + FOR bom IN + 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 + LOOP + -- Stocked Items "leaf node" + IF (bom.ProductType = 'I' AND bom.IsStocked = 'Y') THEN + -- Get ProductQty + SELECT COALESCE(SUM(QtyOrdered), 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=v_Warehouse_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 := 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=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; + 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; - 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' ; -/* - *This file is part of Adempiere ERP Bazaar - *http://www.adempiere.org - *Copyright (C) 2006-2008 victor.perez@e-evolution.com, e-Evolution - *This program is free software; you can redistribute it and/or - *modify it under the terms of the GNU General Public License - *as published by the Free Software Foundation; either version 2 - *of the License, or (at your option) any later version. - * - *This program is distributed in the hope that it will be useful, - *but WITHOUT ANY WARRANTY; without even the implied warranty of - *MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the - *GNU General Public License for more details. - * - *You should have received a copy of the GNU General Public License - *along with this program; if not, write to the Free Software - *Foundation, Inc., 51 Franklin Street, Fifth Floor, Boston, MA 02110-1301, USA.of - * Return quantity ordered for BOM ASI - */ -CREATE OR REPLACE FUNCTION BomqtyorderedASI -( - p_Product_ID numeric, - AttributeSetInstance_ID numeric, - p_Warehouse_ID numeric, - p_Locator_ID numeric -- Only used, if warehouse is null -) -RETURNS numeric -AS -$BODY$ +$bomqtyordered$ LANGUAGE plpgsql; + + + +-- ?? CREATE OR REPLACE FUNCTION BomqtyorderedASI + +CREATE OR REPLACE FUNCTION bomqtyreserved(p_Product_ID numeric, p_Warehouse_ID numeric, p_Locator_ID numeric) + RETURNS numeric AS $bomqtyreserved$ DECLARE - v_Warehouse_ID numeric; - v_Quantity numeric := 99999; -- unlimited + 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; + v_ProductQty NUMERIC; + v_StdPrecision NUMERIC; + 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; --- 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 COALESCE(SUM(QtyOrdered), 0) - INTO v_ProductQty - FROM M_STORAGE s - WHERE M_Product_ID=p_Product_ID - AND EXISTS (SELECT * FROM M_LOCATOR l WHERE s.M_Locator_ID=l.M_Locator_ID - AND l.M_Warehouse_ID=v_Warehouse_ID) - AND (s.M_AttributeSetInstance_ID = AttributeSetInstance_ID OR COALESCE(AttributeSetInstance_ID,0) = 0); - -- - RETURN v_ProductQty; - END IF; - - -- Go though BOM --- DBMS_OUTPUT.PUT_LINE('BOM'); - FOR bom IN - -- Get BOM Product info - SELECT bl.M_Product_ID AS M_ProductBOM_ID, CASE WHEN bl.IsQtyPercentage = 'N' THEN bl.QtyBOM ELSE bl.QtyBatch / 100 END AS BomQty , p.IsBOM , p.IsStocked, p.ProductType - FROM PP_PRODUCT_BOM b - INNER JOIN M_PRODUCT p ON (p.M_Product_ID=b.M_Product_ID) - INNER JOIN PP_PRODUCT_BOMLINE bl ON (bl.PP_Product_BOM_ID=b.PP_Product_BOM_ID) - WHERE b.M_Product_ID = p_Product_ID - LOOP - -- Stocked Items "leaf node" - IF (bom.ProductType = 'I' AND bom.IsStocked = 'Y') THEN - -- Get ProductQty - SELECT COALESCE(SUM(QtyOrdered), 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=v_Warehouse_ID) - AND (s.M_AttributeSetInstance_ID = AttributeSetInstance_ID OR COALESCE(AttributeSetInstance_ID,0) = 0); - -- 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 := BomqtyorderedASI (bom.M_ProductBOM_ID, AttributeSetInstance_ID, v_Warehouse_ID, p_Locator_ID); - -- How much can we make overall - IF (v_ProductQty < v_Quantity) THEN - v_Quantity := v_ProductQty; + 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; - 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' ; - -/* - *This file is part of Adempiere ERP Bazaar - *http://www.adempiere.org - *Copyright (C) 2006-2008 victor.perez@e-evolution.com, e-Evolution - *This program is free software; you can redistribute it and/or - *modify it under the terms of the GNU General Public License - *as published by the Free Software Foundation; either version 2 - *of the License, or (at your option) any later version. - * - *This program is distributed in the hope that it will be useful, - *but WITHOUT ANY WARRANTY; without even the implied warranty of - *MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the - *GNU General Public License for more details. - * - *You should have received a copy of the GNU General Public License - *along with this program; if not, write to the Free Software - *Foundation, Inc., 51 Franklin Street, Fifth Floor, Boston, MA 02110-1301, USA.of - * Return quantity reserved for BOM - */ -CREATE OR REPLACE FUNCTION Bomqtyreserved -( - p_Product_ID numeric, - p_Warehouse_ID numeric, - p_Locator_ID numeric -- Only used, if warehouse is null -) -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 + IF (v_Warehouse_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 + -- 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; - 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(QtyReserved), 0) - INTO v_ProductQty - FROM M_STORAGE s - WHERE M_Product_ID=p_Product_ID - AND EXISTS (SELECT * FROM M_LOCATOR l WHERE s.M_Locator_ID=l.M_Locator_ID - AND l.M_Warehouse_ID=v_Warehouse_ID); - -- - RETURN v_ProductQty; - END IF; - - -- Go though BOM --- DBMS_OUTPUT.PUT_LINE('BOM'); - FOR bom IN - -- Get BOM Product info - SELECT bl.M_Product_ID AS M_ProductBOM_ID, CASE WHEN bl.IsQtyPercentage = 'N' THEN bl.QtyBOM ELSE bl.QtyBatch / 100 END AS BomQty , p.IsBOM , p.IsStocked, p.ProductType - FROM PP_PRODUCT_BOM b - INNER JOIN M_PRODUCT p ON (p.M_Product_ID=b.M_Product_ID) - INNER JOIN PP_PRODUCT_BOMLINE bl ON (bl.PP_Product_BOM_ID=b.PP_Product_BOM_ID) - WHERE b.M_Product_ID = p_Product_ID - LOOP - -- Stocked Items "leaf node" - IF (bom.ProductType = 'I' AND bom.IsStocked = 'Y') THEN + -- Stocked item + ELSIF (v_IsStocked='Y') THEN -- Get ProductQty SELECT COALESCE(SUM(QtyReserved), 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 + FROM M_Storage s + WHERE M_Product_ID=p_Product_ID + AND EXISTS (SELECT * FROM M_Locator l WHERE s.M_Locator_ID=l.M_Locator_ID AND l.M_Warehouse_ID=v_Warehouse_ID); - -- Get Rounding Precision + -- + RETURN v_ProductQty; + END IF; + + -- Go though BOM + + FOR bom IN + 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 + LOOP + -- Stocked Items "leaf node" + IF (bom.ProductType = 'I' AND bom.IsStocked = 'Y') THEN + -- Get ProductQty + SELECT COALESCE(SUM(QtyReserved), 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=v_Warehouse_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 := 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=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; + 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; - 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' ; -/* - *This file is part of Adempiere ERP Bazaar - *http://www.adempiere.org - *Copyright (C) 2006-2008 victor.perez@e-evolution.com, e-Evolution - *This program is free software; you can redistribute it and/or - *modify it under the terms of the GNU General Public License - *as published by the Free Software Foundation; either version 2 - *of the License, or (at your option) any later version. - * - *This program is distributed in the hope that it will be useful, - *but WITHOUT ANY WARRANTY; without even the implied warranty of - *MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the - *GNU General Public License for more details. - * - *You should have received a copy of the GNU General Public License - *along with this program; if not, write to the Free Software - *Foundation, Inc., 51 Franklin Street, Fifth Floor, Boston, MA 02110-1301, USA.of - * Return quantity reserved for BOM ASI - */ -CREATE OR REPLACE FUNCTION BomqtyreservedASI -( - p_Product_ID numeric, - AttributeSetInstance_ID numeric, - p_Warehouse_ID numeric, - p_Locator_ID numeric -- Only used, if warehouse is null -) -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; --- DBMS_OUTPUT.PUT_LINE('Warehouse=' || v_Warehouse_ID); +$bomqtyreserved$ LANGUAGE plpgsql; - -- 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(QtyReserved), 0) - INTO v_ProductQty - FROM M_STORAGE s - WHERE M_Product_ID=p_Product_ID - AND EXISTS (SELECT * FROM M_LOCATOR l WHERE s.M_Locator_ID=l.M_Locator_ID - AND l.M_Warehouse_ID=v_Warehouse_ID) - AND (s.M_AttributeSetInstance_ID = AttributeSetInstance_ID OR COALESCE(AttributeSetInstance_ID,0) = 0); - -- - RETURN v_ProductQty; - END IF; - - -- Go though BOM --- DBMS_OUTPUT.PUT_LINE('BOM'); - FOR bom IN - --Get BOM Product info - SELECT bl.M_Product_ID AS M_ProductBOM_ID, CASE WHEN bl.IsQtyPercentage = 'N' THEN bl.QtyBOM ELSE bl.QtyBatch / 100 END AS BomQty , p.IsBOM , p.IsStocked, p.ProductType - FROM PP_PRODUCT_BOM b - INNER JOIN M_PRODUCT p ON (p.M_Product_ID=b.M_Product_ID) - INNER JOIN PP_PRODUCT_BOMLINE bl ON (bl.PP_Product_BOM_ID=b.PP_Product_BOM_ID) - WHERE b.M_Product_ID = p_Product_ID - LOOP - -- Stocked Items "leaf node" - IF (bom.ProductType = 'I' AND bom.IsStocked = 'Y') THEN - -- Get ProductQty - SELECT COALESCE(SUM(QtyReserved), 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=v_Warehouse_ID) - AND (s.M_AttributeSetInstance_ID = AttributeSetInstance_ID OR COALESCE(AttributeSetInstance_ID,0) = 0); - -- 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 := BomqtyreservedASI (bom.M_ProductBOM_ID, AttributeSetInstance_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' ; +-- ?? CREATE OR REPLACE FUNCTION BomqtyreservedASI CREATE OR REPLACE FUNCTION bpartnerRemitLocation(p_C_BPartner_ID C_BPartner.C_BPartner_ID%TYPE) RETURNS numeric AS $body$