From da55fffef02385c03945fb5ca30b0f42a8961161 Mon Sep 17 00:00:00 2001 From: robert Date: Tue, 15 Oct 2024 11:18:04 +0200 Subject: [PATCH] feat: refs #8108 addMoreTablesTag --- db/routines/vn/procedures/entry_transfer.sql | 121 ++++++++++++++++++ .../11300-limeMedeola/00-firstScript.sql | 72 ++++++++++- 2 files changed, 189 insertions(+), 4 deletions(-) create mode 100644 db/routines/vn/procedures/entry_transfer.sql diff --git a/db/routines/vn/procedures/entry_transfer.sql b/db/routines/vn/procedures/entry_transfer.sql new file mode 100644 index 000000000..6d7da2b37 --- /dev/null +++ b/db/routines/vn/procedures/entry_transfer.sql @@ -0,0 +1,121 @@ +DELIMITER $$ +CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`entry_transfer`(vOriginalEntry INT, OUT vNewEntry 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 +*/ + + DECLARE vNewEntryFk INT; + DECLARE vTravelFk INT; + DECLARE vWarehouseFk INT; + + DECLARE EXIT HANDLER FOR SQLEXCEPTION + BEGIN + ROLLBACK; + RESIGNAL; + END; + + -- Clonar la entrada + CALL entry_clone(vOriginalEntry,vNewEntryFk); + + START TRANSACTION; + + -- Hay que crear un nuevo travel, con salida hoy y llegada mañana y asignar la entrada nueva al nuevo travel. + INSERT INTO travel( + shipped, + landed, + warehouseInFk, + warehouseOutFk, + `ref`, + isReceived, + agencyModeFk) + SELECT util.VN_CURDATE(), + util.VN_CURDATE() + INTERVAL 1 DAY, + t.warehouseInFk, + t.warehouseInFk, + 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(); + + UPDATE entry + SET travelFk = vTravelFk + 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 tBuy + ENGINE = MEMORY + SELECT tBuy.itemFk, IFNULL(iss.visible,0) visible, tBuy.totalQuantity, IFNULL(sales.sold,0) sold + FROM (SELECT b.itemFk, SUM(b.quantity) totalQuantity + FROM buy b + WHERE b.entryFk = vOriginalEntry + GROUP BY b.itemFk + ) tBuy + LEFT JOIN ( + SELECT ish.itemFk, SUM(visible) visible + FROM itemShelving ish + JOIN shelving sh ON sh.code = ish.shelvingFk + JOIN parking p ON p.id = sh.parkingFk + JOIN sector s ON s.id = p.sectorFk + WHERE s.warehouseFk = vWarehouseFk + AND sh.parked = util.VN_CURDATE() + GROUP BY ish.itemFk) iss ON tBuy.itemFk = iss.itemFk + LEFT JOIN ( + SELECT s.itemFk, SUM(s.quantity) sold + FROM ticket t + JOIN sale s ON s.ticketFk = t.id + JOIN itemShelvingSale iss ON iss.saleFk = s.id + JOIN itemShelving is2 ON is2.id = iss.itemShelvingFk + JOIN shelving s2 ON s2.code = is2.shelvingFk + WHERE t.shipped BETWEEN util.VN_CURDATE() AND util.dayend(util.VN_CURDATE()) + AND s2.parked = util.VN_CURDATE() + GROUP BY s.itemFk) sales ON sales.itemFk = tBuy.itemFk + WHERE visible = tBuy.totalQuantity + OR iss.itemFk IS NULL; + + UPDATE buy b + JOIN (SELECT * FROM tBuy) sub ON sub.itemFk = b.itemFk + SET b.quantity = sub.totalQuantity - sub.visible - sub.sold + WHERE b.entryFk = vNewEntryFk; + + -- Limpia la nueva entrada + DELETE b.* + FROM buy b + WHERE b.entryFk = vNewEntryFk + AND b.quantity = 0; + + COMMIT; + + SET vNewEntry = vNewEntryFk; + + CALL cache.visible_refresh(@c,TRUE,7); + CALL cache.available_refresh(@c, TRUE, 7, util.VN_CURDATE()); + +END$$ +DELIMITER ; diff --git a/db/versions/11300-limeMedeola/00-firstScript.sql b/db/versions/11300-limeMedeola/00-firstScript.sql index 21920b692..313a65e81 100644 --- a/db/versions/11300-limeMedeola/00-firstScript.sql +++ b/db/versions/11300-limeMedeola/00-firstScript.sql @@ -79,7 +79,71 @@ UPDATE vn.tag WHERE name= 'Tronco'; -GRANT SELECT, UPDATE, INSERT, DELETE ON TABLE vn.itemFarmingTag TO logisticAssist; -GRANT SELECT, UPDATE, INSERT, DELETE ON TABLE vn.itemWrappingTag TO logisticAssist; -GRANT SELECT, UPDATE, INSERT, DELETE ON TABLE vn.itemLanguageTag TO logisticAssist; -GRANT SELECT, UPDATE, INSERT, DELETE ON TABLE vn.itemStemTag TO logisticAssist; \ No newline at end of file +CREATE TABLE IF NOT EXISTS `vn`.`itemBreederTag` ( + `id` int(11) UNSIGNED NOT NULL AUTO_INCREMENT, + `name` varchar(50) DEFAULT NULL, + PRIMARY KEY (`id`), + UNIQUE KEY `name_UNIQUE` (`name`) +) ENGINE=InnoDB AUTO_INCREMENT=1 DEFAULT + CHARSET=utf8mb3 COLLATE=utf8mb3_unicode_ci; + +INSERT IGNORE INTO `vn`.`itemBreederTag` (`name`) VALUES ('David Austin'); + +UPDATE vn.tag + SET isFree=0, + sourceTable='itemBreederTag' + WHERE name= 'Obtentor'; + + + +CREATE TABLE IF NOT EXISTS `vn`.`itemBaseTag` ( + `id` int(11) UNSIGNED NOT NULL AUTO_INCREMENT, + `name` varchar(50) DEFAULT NULL, + PRIMARY KEY (`id`), + UNIQUE KEY `name_UNIQUE` (`name`) +) ENGINE=InnoDB AUTO_INCREMENT=1 DEFAULT + CHARSET=utf8mb3 COLLATE=utf8mb3_unicode_ci; + +INSERT IGNORE INTO `vn`.`itemBaseTag` (`name`) VALUES ('Biodegradable'); +INSERT IGNORE INTO `vn`.`itemBaseTag` (`name`) VALUES ('Caballete'); +INSERT IGNORE INTO `vn`.`itemBaseTag` (`name`) VALUES ('Cerámica'); +INSERT IGNORE INTO `vn`.`itemBaseTag` (`name`) VALUES ('Cristal'); +INSERT IGNORE INTO `vn`.`itemBaseTag` (`name`) VALUES ('Plástico por inyección'); +INSERT IGNORE INTO `vn`.`itemBaseTag` (`name`) VALUES ('Madera'); +INSERT IGNORE INTO `vn`.`itemBaseTag` (`name`) VALUES ('Plástico'); +INSERT IGNORE INTO `vn`.`itemBaseTag` (`name`) VALUES ('Rígido'); +INSERT IGNORE INTO `vn`.`itemBaseTag` (`name`) VALUES ('Ruedas'); +INSERT IGNORE INTO `vn`.`itemBaseTag` (`name`) VALUES ('Sin soporte rígido'); + +UPDATE vn.tag + SET isFree=0, + sourceTable='itemBaseTag' + WHERE name= 'Soporte'; + + + +CREATE TABLE IF NOT EXISTS `vn`.`itemVatRateTag` ( + `id` int(11) UNSIGNED NOT NULL AUTO_INCREMENT, + `name` varchar(50) DEFAULT NULL, + PRIMARY KEY (`id`), + UNIQUE KEY `name_UNIQUE` (`name`) +) ENGINE=InnoDB AUTO_INCREMENT=1 DEFAULT + CHARSET=utf8mb3 COLLATE=utf8mb3_unicode_ci; + +INSERT IGNORE INTO `vn`.`itemVatRateTag` (`name`) VALUES ('General'); +INSERT IGNORE INTO `vn`.`itemVatRateTag` (`name`) VALUES ('Reducido'); + + +UPDATE vn.tag + SET isFree=0, + sourceTable='itemVatRateTag' + WHERE name= 'Tipo de IVA'; + + +GRANT SELECT, UPDATE, INSERT, DELETE ON TABLE vn.itemFarmingTag TO logisticAssist; +GRANT SELECT, UPDATE, INSERT, DELETE ON TABLE vn.itemWrappingTag TO logisticAssist; +GRANT SELECT, UPDATE, INSERT, DELETE ON TABLE vn.itemLanguageTag TO logisticAssist; +GRANT SELECT, UPDATE, INSERT, DELETE ON TABLE vn.itemStemTag TO logisticAssist; +GRANT SELECT, UPDATE, INSERT, DELETE ON TABLE vn.itemWrappingTag TO logisticAssist; +GRANT SELECT, UPDATE, INSERT, DELETE ON TABLE vn.itemBaseTag TO logisticAssist; +GRANT SELECT, UPDATE, INSERT, DELETE ON TABLE vn.itemBreederTag TO logisticAssist; \ No newline at end of file