DELIMITER $$ CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn2008`.`availableTraslate`( vWarehouseLanding INT, vDated DATE, vWarehouseShipment INT) proc: BEGIN DECLARE vDatedFrom DATE; DECLARE vDatedTo DATETIME; DECLARE vDatedReserve DATETIME; DECLARE vDatedInventory DATE; IF vDated < util.VN_CURDATE() THEN LEAVE proc; END IF; CALL vn.item_getStock (vWarehouseLanding, vDated, NULL); -- Calcula algunos parĂ¡metros necesarios SET vDatedFrom = TIMESTAMP(vDated, '00:00:00'); SET vDatedTo = TIMESTAMP(TIMESTAMPADD(DAY, 4, vDated), '23:59:59'); SELECT FechaInventario INTO vDatedInventory FROM tblContadores; SELECT SUBTIME(util.VN_NOW(), reserveTime) INTO vDatedReserve FROM hedera.orderConfig; -- Calcula el ultimo dia de vida para cada producto DROP TEMPORARY TABLE IF EXISTS itemRange; CREATE TEMPORARY TABLE itemRange (PRIMARY KEY (itemFk)) ENGINE = MEMORY SELECT c.itemFk, MAX(t.landed) dated FROM vn.buy c JOIN vn.entry e ON c.entryFk = e.id JOIN vn.travel t ON t.id = e.travelFk JOIN vn.warehouse w ON w.id = t.warehouseInFk WHERE t.landed BETWEEN vDatedInventory AND vDatedFrom AND t.warehouseInFk = vWarehouseLanding AND NOT e.isExcludedFromAvailable AND NOT e.isRaid GROUP BY c.itemFk; -- Tabla con el ultimo dia de last_buy para cada producto que hace un replace de la anterior CALL vn.buyUltimate(vWarehouseShipment, util.VN_CURDATE()); INSERT INTO itemRange SELECT t.itemFk, tr.landed FROM tmp.buyUltimate t JOIN vn.buy b ON b.id = t.buyFk JOIN vn.entry e ON e.id = b.entryFk JOIN vn.travel tr ON tr.id = e.travelFk LEFT JOIN itemRange i ON t.itemFk = i.itemFk WHERE t.warehouseFk = vWarehouseShipment AND NOT e.isRaid ON DUPLICATE KEY UPDATE itemRange.dated = GREATEST(itemRange.dated, tr.landed); DROP TEMPORARY TABLE IF EXISTS itemRangeLive; CREATE TEMPORARY TABLE itemRangeLive (PRIMARY KEY (itemFk)) ENGINE = MEMORY SELECT ir.itemFk, TIMESTAMP(TIMESTAMPADD(DAY, it.life, ir.dated), '23:59:59') dated FROM itemRange ir JOIN vn.item i ON i.id = ir.itemFk JOIN vn.itemType it ON it.id = i.typeFk HAVING dated >= vDatedFrom OR dated IS NULL; -- Calcula el ATP DROP TEMPORARY TABLE IF EXISTS tmp.itemCalc; CREATE TEMPORARY TABLE tmp.itemCalc (INDEX (itemFk,warehouseFk)) ENGINE = MEMORY SELECT i.itemFk, vWarehouseLanding warehouseFk, i.shipped dated, i.quantity FROM vn.itemTicketOut i JOIN itemRangeLive ir ON ir.itemFK = i.item_id WHERE i.shipped >= vDatedFrom AND (ir.dated IS NULL OR i.shipped <= ir.dated) AND i.warehouseFk = vWarehouseLanding UNION ALL SELECT b.itemFk, vWarehouseLanding, t.landed, b.quantity FROM vn.buy b JOIN vn.entry e ON b.entryFk = e.id JOIN vn.travel t ON t.id = e.travelFk JOIN itemRangeLive ir ON ir.itemFk = b.itemFk WHERE NOT e.isExcludedFromAvailable AND b.quantity <> 0 AND NOT e.isRaid AND t.warehouseInFk = vWarehouseLanding AND t.landed >= vDatedFrom AND (ir.dated IS NULL OR t.landed <= ir.dated) UNION ALL SELECT i.itemFk, vWarehouseLanding, i.shipped, i.quantity FROM vn.itemEntryOut i JOIN itemRangeLive ir ON ir.itemFk = i.itemFk WHERE i.shipped >= vDatedFrom AND (ir.dated IS NULL OR i.shipped <= ir.dated) AND i.warehouseOutFk = vWarehouseLanding UNION ALL SELECT r.item_id, vWarehouseLanding, r.shipment, -r.amount FROM hedera.order_row r JOIN hedera.`order` o ON o.id = r.order_id JOIN itemRangeLive ir ON ir.itemFk = r.item_id WHERE r.shipment >= vDatedFrom AND (ir.dated IS NULL OR r.shipment <= ir.dated) AND r.warehouse_id = vWarehouseLanding AND r.created >= vDatedReserve AND NOT o.confirmed; CALL vn.item_getAtp(vDated); DROP TEMPORARY TABLE IF EXISTS availableTraslate; CREATE TEMPORARY TABLE availableTraslate (PRIMARY KEY (item_id)) ENGINE = MEMORY SELECT t.item_id, SUM(stock) available FROM ( SELECT ti.itemFk item_id, stock FROM tmp.itemList ti JOIN itemRange ir ON ir.itemFk = ti.itemFk UNION ALL SELECT itemFk, quantity FROM tmp.itemAtp ) t GROUP BY t.item_id HAVING available <> 0; DROP TEMPORARY TABLE tmp.itemList, itemRange, itemRangeLive; END$$ DELIMITER ;