salix/db/routines/vn/procedures/item_calcVisible.sql

63 lines
2.0 KiB
SQL

DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`item_calcVisible`(
vSelf INT,
vWarehouseFk INT
)
BEGIN
/**
* Calcula el visible de un artículo o de todos.
*
* @param vWarehouse Warehouse id
* @param vSelf Item id
* @param tmp.itemVisible(item_id, stock, visible)
*/
DECLARE vDated DATE DEFAULT util.VN_CURDATE();
DECLARE vTomorrow DATETIME DEFAULT util.tomorrow();
INSERT INTO tmp.itemVisible(item_id, visible)
SELECT itemFk, SUM(quantity)
FROM (
SELECT i.itemFk, i.quantity
FROM itemTicketOut i
LEFT JOIN ticketState ts ON ts.ticketFk = i.ticketFk
JOIN `state` s ON s.id = ts.stateFk
JOIN warehouse w ON w.id = i.warehouseFk
LEFT JOIN (
SELECT DISTINCT st.saleFk
FROM saleTracking st
JOIN state s ON s.id = st.stateFk
WHERE st.created > vDated
AND (s.isPicked OR st.isChecked)
) stPrevious ON `stPrevious`.`saleFk` = i.saleFk
WHERE (vWarehouseFk IS NULL OR i.warehouseFk = vWarehouseFk)
AND (vSelf IS NULL OR i.itemFk = vSelf)
AND (s.isPicked OR i.reserved OR stPrevious.saleFk)
AND i.shipped >= vDated AND i.shipped < vTomorrow
AND w.isComparative
UNION ALL
SELECT iei.itemFk, iei.quantity
FROM itemEntryIn iei
JOIN warehouse w ON w.id = iei.warehouseInFk
WHERE iei.isReceived
AND iei.landed >= vDated AND iei.landed < vTomorrow
AND (vWarehouseFk IS NULL OR iei.warehouseInFk = vWarehouseFk)
AND (vSelf IS NULL OR iei.itemFk = vSelf)
AND NOT iei.isVirtualStock
AND w.isComparative
UNION ALL
SELECT ieo.itemFk, ieo.quantity
FROM itemEntryOut ieo
JOIN warehouse w ON w.id = ieo.warehouseOutFk
WHERE ieo.isDelivered
AND ieo.shipped >= vDated
AND ieo.shipped < vTomorrow
AND (vWarehouseFk IS NULL OR ieo.warehouseOutFk = vWarehouseFk)
AND (vSelf IS NULL OR ieo.itemFk = vSelf)
AND w.isComparative
) t
GROUP BY itemFk
ON DUPLICATE KEY UPDATE
visible = IFNULL(stock, 0) + VALUES(visible);
END$$
DELIMITER ;