DELIMITER $$ CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`entry_transfer`( vOriginalEntry INT, OUT vNewEntryFk INT ) BEGIN /** * Adelanta a mañana la mercancia de una entrada a partir de lo que hay ubicado en el almacén * * @param vOriginalEntry entrada que se quiera adelantar * @param vNewEntry nueva entrada creada */ DECLARE vTravelFk INT; DECLARE vWarehouseFk INT; DECLARE vWarehouseInFk INT; DECLARE vWarehouseOutFk INT; DECLARE vRef INT; DECLARE vIsReceived INT; DECLARE vAgencyModeFk INT; DECLARE vTomorrow DATETIME DEFAULT util.tomorrow(); DECLARE vIsRequiredTx BOOL DEFAULT NOT @@in_transaction; DECLARE EXIT HANDLER FOR SQLEXCEPTION BEGIN CALL util.tx_rollback(vIsRequiredTx); RESIGNAL; END; -- Clonar la entrada CALL entry_clone(vOriginalEntry, vNewEntryFk); CALL util.tx_start(vIsRequiredTx); -- Hay que crear un nuevo travel, con salida hoy y llegada mañana y asignar la entrada nueva al nuevo travel. SELECT t.warehouseInFk, t.warehouseOutFk, t.`ref`, t.isReceived, t.agencyModeFk INTO vWarehouseInFk, vWarehouseOutFk, vRef, vIsReceived, vAgencyModeFk FROM travel t JOIN entry e ON e.travelFk = t.id WHERE e.id = vOriginalEntry; SELECT id INTO vTravelFk FROM travel t WHERE shipped = util.VN_CURDATE() AND landed = vTomorrow AND warehouseInFk = vWarehouseInFk AND warehouseOutFk = vWarehouseOutFk AND `ref` = vRef AND isReceived =vIsReceived AND agencyModeFk = vAgencyModeFk; IF vTravelFk IS NULL THEN INSERT INTO travel( shipped, landed, warehouseInFk, warehouseOutFk, `ref`, isReceived, agencyModeFk) SELECT util.VN_CURDATE(), vTomorrow, t.warehouseInFk, t.warehouseOutFk, t.`ref`, t.isReceived, t.agencyModeFk FROM travel t JOIN entry e ON e.travelFk = t.id WHERE e.id = vOriginalEntry; SET vTravelFk = LAST_INSERT_ID(); END IF; UPDATE entry SET travelFk = vTravelFk, evaNotes = vOriginalEntry WHERE id = vNewEntryFk; -- Poner a 0 las cantidades UPDATE buy b SET b.quantity = 0, b.stickers = 0 WHERE b.entryFk = vNewEntryFk; -- Eliminar duplicados DELETE b FROM buy b LEFT JOIN (SELECT b.id, b.itemFk FROM buy b WHERE b.entryFk = vNewEntryFk GROUP BY b.itemFk) tBuy ON tBuy.id = b.id WHERE b.entryFk = vNewEntryFk AND tBuy.id IS NULL; SELECT t.warehouseInFk INTO vWarehouseFk FROM travel t JOIN entry e ON e.travelFk = t.id WHERE e.id = vOriginalEntry; -- Actualizar la nueva entrada con lo que no está ubicado HOY, descontando lo vendido HOY de esas ubicaciones CREATE OR REPLACE TEMPORARY TABLE buys WITH tBuy AS ( SELECT b.itemFk, SUM(b.quantity) totalQuantity FROM vn.buy b WHERE b.entryFk = vOriginalEntry GROUP BY b.itemFk ), itemShelvings AS ( SELECT ish.itemFk, SUM(ish.visible) visible FROM vn.itemShelving ish JOIN vn.shelving sh ON sh.id = ish.shelvingFk JOIN vn.parking p ON p.id = sh.parkingFk JOIN vn.sector s ON s.id = p.sectorFk JOIN vn.buy b ON b.id = ish.buyFk JOIN vn.entry e ON e.id = b.entryFk JOIN tBuy t ON t.itemFk = ish.itemFk WHERE s.warehouseFk = vWarehouseFk AND sh.parked >= util.VN_CURDATE() GROUP BY ish.itemFk ), sales AS ( SELECT s.itemFk, SUM(s.quantity) sold FROM vn.ticket t JOIN vn.sale s ON s.ticketFk = t.id JOIN vn.itemShelvingSale iss ON iss.saleFk = s.id JOIN vn.itemShelving is2 ON is2.id = iss.itemShelvingFk JOIN vn.shelving s2 ON s2.id = is2.shelvingFk JOIN tBuy t ON t.itemFk = s.itemFk WHERE t.shipped BETWEEN util.VN_CURDATE() AND util.dayend(util.VN_CURDATE()) AND s2.parked >= util.VN_CURDATE() GROUP BY s.itemFk ) SELECT tmp.itemFk, IFNULL(iss.visible, 0) visible, tmp.totalQuantity, IFNULL(s.sold, 0) sold FROM tBuy tmp LEFT JOIN itemShelvings iss ON tmp.itemFk = iss.itemFk LEFT JOIN sales s ON s.itemFk = tmp.itemFk WHERE visible < tmp.totalQuantity OR iss.itemFk IS NULL; UPDATE buy b JOIN buys tmp ON tmp.itemFk = b.itemFk SET b.quantity = tmp.totalQuantity - tmp.visible - tmp.sold WHERE b.entryFk = vNewEntryFk; -- Limpia la nueva entrada DELETE FROM buy WHERE entryFk = vNewEntryFk AND quantity = 0; CALL util.tx_commit(vIsRequiredTx); CALL cache.visible_refresh(@c,TRUE,vWarehouseFk); CALL cache.available_refresh(@c, TRUE, vWarehouseFk, util.VN_CURDATE()); END$$ DELIMITER ;