DELIMITER $$ CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`item_getBalance`( vItemFk INT, vWarehouseFk INT, vDate DATETIME ) BEGIN /** * @vItemFk item a buscar * @vWarehouseFk almacen donde buscar * @vDate Si la fecha es null, muestra el histórico desde el inventario. * Si la fecha no es null, muestra histórico desde la fecha pasada. */ DECLARE vDateInventory DATETIME; IF vDate IS NULL THEN SELECT inventoried INTO vDateInventory FROM config; ELSE SELECT mockUtcTime INTO vDateInventory FROM util.config; END IF; CREATE OR REPLACE TEMPORARY TABLE tItemDiary( shipped DATE, `in` INT(11), `out` INT(11), alertLevel INT(11), stateName VARCHAR(20), `name` VARCHAR(50), reference VARCHAR(50), origin INT(11), clientFk INT(11), isPicked INT(11), isTicket TINYINT(1), lineFk INT(11), `order` TINYINT(3) UNSIGNED, clientType VARCHAR(20), claimFk INT(10) UNSIGNED, inventorySupplierFk INT(10) ); INSERT INTO tItemDiary SELECT tr.landed shipped, b.quantity `in`, NULL `out`, st.alertLevel , st.name stateName, s.name `name`, e.invoiceNumber reference, e.id origin, s.id clientFk, IF(st.`code` = 'DELIVERED', TRUE, FALSE) isPicked, FALSE isTicket, b.id lineFk, NULL `order`, NULL clientType, NULL claimFk, ec.inventorySupplierFk 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 state st ON st.`code` = IF( tr.landed < util.VN_CURDATE() OR (util.VN_CURDATE() AND tr.isReceived), 'DELIVERED', 'FREE') JOIN entryConfig ec WHERE tr.landed >= vDateInventory AND vWarehouseFk = tr.warehouseInFk AND (s.id <> ec.inventorySupplierFk OR vDate IS NULL) AND b.itemFk = vItemFk AND e.isExcludedFromAvailable = FALSE AND e.isRaid = FALSE UNION ALL SELECT tr.shipped, NULL, b.quantity, st.alertLevel, st.name, s.name, e.invoiceNumber, e.id, s.id, IF(st.`code` = 'DELIVERED' , TRUE, FALSE), FALSE, b.id, NULL, NULL, NULL, ec.inventorySupplierFk 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 state st ON st.`code` = IF(tr.shipped < util.VN_CURDATE() OR (tr.shipped = util.VN_CURDATE() AND tr.isReceived), 'DELIVERED', 'FREE') JOIN entryConfig ec WHERE tr.shipped >= vDateInventory AND vWarehouseFk = tr.warehouseOutFk AND (s.id <> ec.inventorySupplierFk OR vDate IS NULL) AND b.itemFk = vItemFk AND e.isExcludedFromAvailable = FALSE AND w.isFeedStock = FALSE AND e.isRaid = FALSE UNION ALL SELECT DATE(t.shipped), NULL, s.quantity, st2.alertLevel, st2.name, t.nickname, t.refFk, t.id, t.clientFk, stk.id, TRUE, s.id, st.`order`, ct.`code`, cb.claimFk, NULL FROM sale s JOIN ticket t ON t.id = s.ticketFk LEFT JOIN ticketState ts ON ts.ticketFk = t.id LEFT JOIN state st ON st.`code` = ts.`code` JOIN client c ON c.id = t.clientFk JOIN clientType ct ON ct.id = c.clientTypeFk JOIN state st2 ON st2.`code` = IF(t.shipped < util.VN_CURDATE(), 'DELIVERED', IF (t.shipped > util.dayEnd(util.VN_CURDATE()), 'FREE', IFNULL(ts.code, 'FREE'))) LEFT JOIN state stPrep ON stPrep.`code` = 'PREPARED' LEFT JOIN saleTracking stk ON stk.saleFk = s.id AND stk.stateFk = stPrep.id LEFT JOIN claimBeginning cb ON s.id = cb.saleFk WHERE t.shipped >= vDateInventory AND s.itemFk = vItemFk AND vWarehouseFk =t.warehouseFk ORDER BY shipped, (inventorySupplierFk = clientFk) DESC, alertLevel DESC, isTicket, `order` DESC, isPicked DESC, `in` DESC, `out` DESC; IF vDate IS NULL THEN SET @a := 0; SET @currentLineFk := 0; SET @shipped := ''; SELECT DATE(@shipped:= shipped) shipped, alertLevel, stateName, origin, reference, clientFk, name, `in` invalue, `out`, @a := @a + IFNULL(`in`, 0) - IFNULL(`out`, 0) balance, @currentLineFk := IF (@shipped < util.VN_CURDATE() OR (@shipped = util.VN_CURDATE() AND (isPicked OR a.`code` >= 'ON_PREPARATION')), lineFk, @currentLineFk) lastPreparedLineFk, isTicket, lineFk, isPicked, clientType, claimFk FROM tItemDiary LEFT JOIN alertLevel a ON a.id = tItemDiary.alertLevel; ELSE SELECT SUM(`in`) - SUM(`out`) INTO @a FROM tItemDiary WHERE shipped < vDate; SELECT vDate shipped, 0 alertLevel, 0 stateName, 0 origin, '' reference, 0 clientFk, 'Inventario calculado', @a invalue, NULL `out`, @a balance, 0 lastPreparedLineFk, 0 isTicket, 0 lineFk, 0 isPicked, 0 clientType, 0 claimFk UNION ALL SELECT shipped, alertlevel, stateName, origin, reference, clientFk, name, `in`, `out`, @a := @a + IFNULL(`in`, 0) - IFNULL(`out`, 0), 0, isTicket, lineFk, isPicked, clientType, claimFk FROM tItemDiary WHERE shipped >= vDate; END IF; DROP TEMPORARY TABLE tItemDiary; END$$ DELIMITER ;