60 lines
1.6 KiB
SQL
60 lines
1.6 KiB
SQL
DELIMITER $$
|
|
CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`item_getStock`(
|
|
vWarehouseFk SMALLINT,
|
|
vAvailabled DATETIME,
|
|
vItemFk INT
|
|
)
|
|
BEGIN
|
|
/**
|
|
* Calcula el stock de un artículo de un vWarehouseFk,
|
|
* desde la fecha del inventario hasta el momento anterior a vAvailabled
|
|
*
|
|
* @param vWarehouse Warehouse id
|
|
* @param vAvailabled Maximum time to filter
|
|
* @param vItemFk Item id
|
|
*
|
|
* @return tmp.itemList(itemFk, stock, visible, available)
|
|
*/
|
|
CALL cache.stock_refresh(FALSE);
|
|
|
|
CREATE OR REPLACE TEMPORARY TABLE tmp.itemList
|
|
(UNIQUE INDEX i USING HASH (itemFk))
|
|
ENGINE = MEMORY
|
|
SELECT itemFk,
|
|
SUM(quantity) stock,
|
|
SUM(quantity) visible,
|
|
SUM(quantity) available
|
|
FROM (
|
|
SELECT itemFk, quantity
|
|
FROM itemTicketOut
|
|
WHERE shipped >= util.VN_CURDATE()
|
|
AND shipped < vAvailabled
|
|
AND warehouseFk = vWarehouseFk
|
|
AND (vItemFk IS NULL OR itemFk = vItemFk)
|
|
UNION ALL
|
|
SELECT iei.itemFk, iei.quantity
|
|
FROM itemEntryIn iei
|
|
JOIN item i ON i.id = iei.itemFk
|
|
WHERE iei.availabled >= util.VN_CURDATE()
|
|
AND iei.availabled < vAvailabled
|
|
AND iei.warehouseInFk = vWarehouseFk
|
|
AND (vItemFk IS NULL OR iei.itemFk = vItemFk)
|
|
UNION ALL
|
|
SELECT ieo.itemFk, ieo.quantity
|
|
FROM itemEntryOut ieo
|
|
JOIN item i ON i.id = ieo.itemFk
|
|
WHERE ieo.shipped >= util.VN_CURDATE()
|
|
AND ieo.shipped < vAvailabled
|
|
AND ieo.warehouseOutFk = vWarehouseFk
|
|
AND (vItemFk IS NULL OR ieo.itemFk = vItemFk)
|
|
UNION ALL
|
|
SELECT item_id, amount
|
|
FROM cache.stock
|
|
WHERE warehouse_id = vWarehouseFk
|
|
) sub
|
|
GROUP BY itemFk
|
|
HAVING stock;
|
|
|
|
END$$
|
|
DELIMITER ;
|