1003965 IDEMPIERE-1950 Product Info Reservation not showing if Warehouse > Reservation Locator not populated.

This commit is contained in:
Heng Sin Low 2014-04-29 20:09:26 +08:00
parent bb7dd0a1cc
commit 2915294c5c
6 changed files with 551 additions and 45 deletions

View File

@ -65,12 +65,13 @@ BEGIN
-- Stocked item -- Stocked item
ELSIF (v_IsStocked='Y') THEN ELSIF (v_IsStocked='Y') THEN
-- Get ProductQty -- Get ProductQty
SELECT NVL(SUM(QtyOrdered), 0) SELECT NVL(SUM(Qty), 0)
INTO v_ProductQty INTO v_ProductQty
FROM M_STORAGE s FROM M_StorageReservation
WHERE M_Product_ID=p_Product_ID WHERE M_Product_ID=p_Product_ID
AND EXISTS (SELECT * FROM M_LOCATOR l WHERE s.M_Locator_ID=l.M_Locator_ID AND M_Warehouse_ID=v_Warehouse_ID
AND l.M_Warehouse_ID=v_Warehouse_ID); AND IsSOTrx='N'
AND IsActive='Y';
-- --
RETURN v_ProductQty; RETURN v_ProductQty;
END IF; END IF;
@ -81,12 +82,13 @@ BEGIN
-- Stocked Items "leaf node" -- Stocked Items "leaf node"
IF (bom.ProductType = 'I' AND bom.IsStocked = 'Y') THEN IF (bom.ProductType = 'I' AND bom.IsStocked = 'Y') THEN
-- Get ProductQty -- Get ProductQty
SELECT NVL(SUM(QtyOrdered), 0) SELECT NVL(SUM(Qty), 0)
INTO v_ProductQty INTO v_ProductQty
FROM M_STORAGE s FROM M_StorageReservation
WHERE M_Product_ID=bom.M_ProductBOM_ID WHERE M_Product_ID=p_Product_ID
AND EXISTS (SELECT * FROM M_LOCATOR l WHERE s.M_Locator_ID=l.M_Locator_ID AND M_Warehouse_ID=v_Warehouse_ID
AND l.M_Warehouse_ID=v_Warehouse_ID); AND IsSOTrx='N'
AND IsActive='Y';
-- Get Rounding Precision -- Get Rounding Precision
SELECT NVL(MAX(u.StdPrecision), 0) SELECT NVL(MAX(u.StdPrecision), 0)
INTO v_StdPrecision INTO v_StdPrecision

View File

@ -65,12 +65,13 @@ BEGIN
-- Stocked item -- Stocked item
ELSIF (v_IsStocked='Y') THEN ELSIF (v_IsStocked='Y') THEN
-- Get ProductQty -- Get ProductQty
SELECT NVL(SUM(QtyReserved), 0) SELECT NVL(SUM(Qty), 0)
INTO v_ProductQty INTO v_ProductQty
FROM M_STORAGE s FROM M_StorageReservation
WHERE M_Product_ID=p_Product_ID WHERE M_Product_ID=p_Product_ID
AND EXISTS (SELECT * FROM M_LOCATOR l WHERE s.M_Locator_ID=l.M_Locator_ID AND M_Warehouse_ID=v_Warehouse_ID
AND l.M_Warehouse_ID=v_Warehouse_ID); AND IsSOTrx='Y'
AND IsActive='Y';
-- --
RETURN v_ProductQty; RETURN v_ProductQty;
END IF; END IF;
@ -81,12 +82,13 @@ BEGIN
-- Stocked Items "leaf node" -- Stocked Items "leaf node"
IF (bom.ProductType = 'I' AND bom.IsStocked = 'Y') THEN IF (bom.ProductType = 'I' AND bom.IsStocked = 'Y') THEN
-- Get ProductQty -- Get ProductQty
SELECT NVL(SUM(QtyReserved), 0) SELECT NVL(SUM(Qty), 0)
INTO v_ProductQty INTO v_ProductQty
FROM M_STORAGE s FROM M_StorageReservation
WHERE M_Product_ID=bom.M_ProductBOM_ID 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 M_Warehouse_ID=v_Warehouse_ID
AND l.M_Warehouse_ID=v_Warehouse_ID); AND IsSOTrx='Y'
AND IsActive='Y';
-- Get Rounding Precision -- Get Rounding Precision
SELECT NVL(MAX(u.StdPrecision), 0) SELECT NVL(MAX(u.StdPrecision), 0)
INTO v_StdPrecision INTO v_StdPrecision

View File

@ -24,7 +24,6 @@ BEGIN
IF (v_Warehouse_ID IS NULL) THEN IF (v_Warehouse_ID IS NULL) THEN
RETURN 0; RETURN 0;
END IF; END IF;
-- DBMS_OUTPUT.PUT_LINE(''Warehouse='' || v_Warehouse_ID);
-- Check, if product exists and if it is stocked -- Check, if product exists and if it is stocked
BEGIN BEGIN
@ -44,18 +43,18 @@ BEGIN
-- Stocked item -- Stocked item
ELSIF (v_IsStocked='Y') THEN ELSIF (v_IsStocked='Y') THEN
-- Get ProductQty -- Get ProductQty
SELECT COALESCE(SUM(QtyOrdered), 0) SELECT COALESCE(SUM(Qty), 0)
INTO v_ProductQty INTO v_ProductQty
FROM M_STORAGE s FROM M_StorageReservation
WHERE M_Product_ID=p_Product_ID WHERE M_Product_ID=p_Product_ID
AND EXISTS (SELECT * FROM M_LOCATOR l WHERE s.M_Locator_ID=l.M_Locator_ID AND M_Warehouse_ID=v_Warehouse_ID
AND l.M_Warehouse_ID=v_Warehouse_ID); AND IsSOTrx='N'
AND IsActive='Y';
-- --
RETURN v_ProductQty; RETURN v_ProductQty;
END IF; END IF;
-- Go though BOM -- Go though BOM
-- DBMS_OUTPUT.PUT_LINE(''BOM'');
FOR bom IN FOR bom IN
-- Get BOM Product info -- Get BOM Product info
SELECT b.M_ProductBOM_ID, b.BOMQty, p.IsBOM, p.IsStocked, p.ProductType SELECT b.M_ProductBOM_ID, b.BOMQty, p.IsBOM, p.IsStocked, p.ProductType
@ -68,12 +67,13 @@ BEGIN
-- Stocked Items "leaf node" -- Stocked Items "leaf node"
IF (bom.ProductType = 'I' AND bom.IsStocked = 'Y') THEN IF (bom.ProductType = 'I' AND bom.IsStocked = 'Y') THEN
-- Get ProductQty -- Get ProductQty
SELECT COALESCE(SUM(QtyOrdered), 0) SELECT COALESCE(SUM(Qty), 0)
INTO v_ProductQty INTO v_ProductQty
FROM M_STORAGE s FROM M_StorageReservation
WHERE M_Product_ID=bom.M_ProductBOM_ID WHERE M_Product_ID=p_Product_ID
AND EXISTS (SELECT * FROM M_LOCATOR l WHERE s.M_Locator_ID=l.M_Locator_ID AND M_Warehouse_ID=v_Warehouse_ID
AND l.M_Warehouse_ID=v_Warehouse_ID); AND IsSOTrx='N'
AND IsActive='Y';
-- Get Rounding Precision -- Get Rounding Precision
SELECT COALESCE(MAX(u.StdPrecision), 0) SELECT COALESCE(MAX(u.StdPrecision), 0)
INTO v_StdPrecision INTO v_StdPrecision
@ -114,6 +114,5 @@ BEGIN
RETURN 0; RETURN 0;
END; END;
$BODY$ $BODY$
LANGUAGE 'plpgsql' LANGUAGE plpgsql VOLATILE;
;

View File

@ -24,7 +24,6 @@ BEGIN
IF (v_Warehouse_ID IS NULL) THEN IF (v_Warehouse_ID IS NULL) THEN
RETURN 0; RETURN 0;
END IF; END IF;
-- DBMS_OUTPUT.PUT_LINE(''Warehouse='' || v_Warehouse_ID);
-- Check, if product exists and if it is stocked -- Check, if product exists and if it is stocked
BEGIN BEGIN
@ -44,18 +43,18 @@ BEGIN
-- Stocked item -- Stocked item
ELSIF (v_IsStocked='Y') THEN ELSIF (v_IsStocked='Y') THEN
-- Get ProductQty -- Get ProductQty
SELECT COALESCE(SUM(QtyReserved), 0) SELECT COALESCE(SUM(Qty), 0)
INTO v_ProductQty INTO v_ProductQty
FROM M_STORAGE s FROM M_StorageReservation
WHERE M_Product_ID=p_Product_ID WHERE M_Product_ID=p_Product_ID
AND EXISTS (SELECT * FROM M_LOCATOR l WHERE s.M_Locator_ID=l.M_Locator_ID AND M_Warehouse_ID=v_Warehouse_ID
AND l.M_Warehouse_ID=v_Warehouse_ID); AND IsSOTrx='Y'
AND IsActive='Y';
-- --
RETURN v_ProductQty; RETURN v_ProductQty;
END IF; END IF;
-- Go though BOM -- Go though BOM
-- DBMS_OUTPUT.PUT_LINE(''BOM'');
FOR bom IN FOR bom IN
-- Get BOM Product info -- Get BOM Product info
SELECT b.M_ProductBOM_ID, b.BOMQty, p.IsBOM, p.IsStocked, p.ProductType SELECT b.M_ProductBOM_ID, b.BOMQty, p.IsBOM, p.IsStocked, p.ProductType
@ -68,12 +67,13 @@ BEGIN
-- Stocked Items "leaf node" -- Stocked Items "leaf node"
IF (bom.ProductType = 'I' AND bom.IsStocked = 'Y') THEN IF (bom.ProductType = 'I' AND bom.IsStocked = 'Y') THEN
-- Get ProductQty -- Get ProductQty
SELECT COALESCE(SUM(QtyReserved), 0) SELECT COALESCE(SUM(Qty), 0)
INTO v_ProductQty INTO v_ProductQty
FROM M_STORAGE s FROM M_StorageReservation
WHERE M_Product_ID=bom.M_ProductBOM_ID 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 M_Warehouse_ID =v_Warehouse_ID
AND l.M_Warehouse_ID=v_Warehouse_ID); AND IsSOTrx='Y'
AND IsActive='Y';
-- Get Rounding Precision -- Get Rounding Precision
SELECT COALESCE(MAX(u.StdPrecision), 0) SELECT COALESCE(MAX(u.StdPrecision), 0)
INTO v_StdPrecision INTO v_StdPrecision
@ -112,6 +112,6 @@ BEGIN
RETURN 0; RETURN 0;
END; END;
$BODY$ $BODY$
LANGUAGE 'plpgsql' LANGUAGE plpgsql VOLATILE;
;

View File

@ -0,0 +1,266 @@
SET SQLBLANKLINES ON
SET DEFINE OFF
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 p.IsBOM='Y'
AND p.IsVerified='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;
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 p.IsBOM='Y'
AND p.IsVerified='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;
/
SELECT register_migration_script('201404290949_Ticket_1003965.sql') FROM dual
;

View File

@ -0,0 +1,237 @@
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 p.IsBOM='Y'
AND p.IsVerified='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 VOLATILE;
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 p.IsBOM='Y'
AND p.IsVerified='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 VOLATILE;
SELECT register_migration_script('201404290949_Ticket_1003965.sql') FROM dual
;