130 lines
4.7 KiB
SQL
130 lines
4.7 KiB
SQL
DROP procedure IF EXISTS `vn`.`item_getBalance`;
|
|
|
|
DELIMITER $$
|
|
USE `vn`$$
|
|
CREATE DEFINER=`root`@`%` PROCEDURE `item_getBalance`(IN vItemId INT, IN vWarehouse INT)
|
|
BEGIN
|
|
DECLARE vDateInventory DATETIME;
|
|
DECLARE vCurdate DATE DEFAULT CURDATE();
|
|
DECLARE vDayEnd DATETIME DEFAULT util.dayEnd(vCurdate);
|
|
|
|
SELECT inventoried INTO vDateInventory FROM config;
|
|
SET @a = 0;
|
|
SET @currentLineFk = 0;
|
|
SET @shipped = '';
|
|
|
|
SELECT DATE(@shipped:= shipped) shipped,
|
|
alertLevel,
|
|
stateName,
|
|
origin,
|
|
reference,
|
|
clientFk,
|
|
name,
|
|
`in`,
|
|
`out`,
|
|
@a := @a + IFNULL(`in`,0) - IFNULL(`out`,0) as balance,
|
|
@currentLineFk := IF (@shipped < CURDATE()
|
|
OR (@shipped = CURDATE() AND (isPicked OR alertLevel >= 2)),
|
|
lineFk,@currentLineFk) lastPreparedLineFk,
|
|
isTicket,
|
|
lineFk,isPicked
|
|
FROM
|
|
( SELECT tr.landed as shipped,
|
|
b.quantity as `in`,
|
|
NULL as `out`,
|
|
al.alertLevel as alertLevel,
|
|
st.name AS stateName,
|
|
s.name as name,
|
|
e.ref as reference,
|
|
e.id as origin,
|
|
s.id as clientFk,
|
|
IF(al.alertLevel = 3, TRUE, FALSE) isPicked,
|
|
FALSE AS isTicket,
|
|
b.id lineFk,
|
|
NULL `order`
|
|
FROM buy b
|
|
JOIN entry e ON e.id = b.entryFk
|
|
JOIN travel tr ON tr.id = e.travelFk
|
|
JOIN supplier s ON s.id = e.supplierFk
|
|
JOIN alertLevel al ON al.alertLevel =
|
|
CASE
|
|
WHEN tr.shipped < CURDATE() THEN 3
|
|
WHEN tr.shipped = CURDATE() AND tr.isReceived = TRUE THEN 3
|
|
ELSE 0
|
|
END
|
|
JOIN state st ON st.code = al.code
|
|
WHERE tr.landed >= vDateInventory
|
|
AND vWarehouse = tr.warehouseInFk
|
|
AND b.itemFk = vItemId
|
|
AND e.isInventory = FALSE
|
|
AND e.isRaid = FALSE
|
|
UNION ALL
|
|
|
|
SELECT tr.shipped,
|
|
NULL as `in`,
|
|
b.quantity as `out`,
|
|
al.alertLevel as alertLevel,
|
|
st.name AS stateName,
|
|
s.name as name,
|
|
e.ref as reference,
|
|
e.id as origin,
|
|
s.id as clientFk,
|
|
IF(al.alertLevel = 3, TRUE, FALSE) isPicked,
|
|
FALSE AS isTicket,
|
|
b.id,
|
|
NULL `order`
|
|
FROM buy b
|
|
JOIN entry e ON e.id = b.entryFk
|
|
JOIN travel tr ON tr.id = e.travelFk
|
|
JOIN warehouse w ON w.id = tr.warehouseOutFk
|
|
JOIN supplier s ON s.id = e.supplierFk
|
|
JOIN alertLevel al ON al.alertLevel =
|
|
CASE
|
|
WHEN tr.shipped < CURDATE() THEN 3
|
|
WHEN tr.shipped = CURDATE() AND tr.isReceived = TRUE THEN 3
|
|
ELSE 0
|
|
END
|
|
JOIN state st ON st.code = al.code
|
|
WHERE tr.shipped >= vDateInventory
|
|
AND vWarehouse =tr.warehouseOutFk
|
|
AND s.id <> 4
|
|
AND b.itemFk = vItemId
|
|
AND e.isInventory = FALSE
|
|
AND w.isFeedStock = FALSE
|
|
AND e.isRaid = FALSE
|
|
UNION ALL
|
|
|
|
SELECT DATE(t.shipped),
|
|
NULL as `in`,
|
|
s.quantity as `out`,
|
|
al.alertLevel as alertLevel,
|
|
st.name AS stateName,
|
|
t.nickname as name,
|
|
t.refFk as reference,
|
|
t.id as origin,
|
|
t.clientFk,
|
|
stk.id as isPicked,
|
|
TRUE as isTicket,
|
|
s.id,
|
|
st.`order`
|
|
FROM sale s
|
|
JOIN ticket t ON t.id = s.ticketFk
|
|
LEFT JOIN ticketState ts ON ts.ticket = t.id
|
|
LEFT JOIN state st ON st.code = ts.code
|
|
JOIN client c ON c.id = t.clientFk
|
|
JOIN alertLevel al ON al.alertLevel =
|
|
CASE
|
|
WHEN t.shipped < curdate() THEN 3
|
|
WHEN t.shipped > util.dayEnd(curdate()) THEN 0
|
|
ELSE IFNULL(ts.alertLevel, 0)
|
|
END
|
|
LEFT JOIN state stPrep ON stPrep.`code` = 'PREPARED'
|
|
LEFT JOIN saleTracking stk ON stk.saleFk = s.id AND stk.stateFk = stPrep.id
|
|
WHERE t.shipped >= vDateInventory
|
|
AND s.itemFk = vItemId
|
|
AND vWarehouse =t.warehouseFk
|
|
ORDER BY shipped, alertLevel DESC, isTicket, `order` DESC, isPicked DESC, `in` DESC, `out` DESC
|
|
) AS itemDiary;
|
|
|
|
END$$
|
|
delimiter ; |