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

58 lines
1.7 KiB
SQL

DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`item_getVisible`(
vWarehouseFk INT,
vDated INT,
vItemFk INT
)
BEGIN
/**
* Calcula el visible de un artículo o de todos.
*
* @param vWarehouse Warehouse id
* @param vDated Max date to filter
* @param vItemFk Item id
* @param tmp.itemVisible(item_id, stock, visible)
*/
DECLARE vTomorrow DATETIME DEFAULT vDated + INTERVAL 1 DAY;
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
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 i.warehouseFk = vWarehouseFk
AND (vItemFk IS NULL OR i.itemFk = vItemFk)
AND (s.isPicked OR i.reserved OR stPrevious.saleFk)
AND i.shipped >= vDated AND i.shipped < vTomorrow
UNION ALL
SELECT itemFk, quantity
FROM itemEntryIn
WHERE isReceived
AND landed >= vDated AND landed < vTomorrow
AND warehouseInFk = vWarehouseFk
AND (vItemFk IS NULL OR itemFk = vItemFk)
AND NOT isVirtualStock
UNION ALL
SELECT itemFk, quantity
FROM itemEntryOut
WHERE isDelivered
AND shipped >= vDated
AND shipped < vTomorrow
AND warehouseOutFk = vWarehouseFk
AND (vItemFk IS NULL OR itemFk = vItemFk)
) t
GROUP BY itemFk
ON DUPLICATE KEY UPDATE
visible = IFNULL(stock, 0) + VALUES(visible);
END$$
DELIMITER ;