/* *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 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(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 -- 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=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); -- 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' ; /* *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$ 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); -- 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); -- 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); -- 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' ; /* *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$ 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); -- 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; 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 */ 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$ 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 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; 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 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 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 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; 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 */ 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' ;