salix/db/routines/vn/procedures/item_cleanFloramondo.sql

201 lines
4.4 KiB
SQL

DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`item_cleanFloramondo`()
BEGIN
/**
* Elimina todos los items repetidos de floramondo
* y los sustituye por el que tiene menor id
*/
DECLARE vItemFrom INT;
DECLARE vItemEnd INT;
DECLARE vItemOld INT;
DECLARE vItemNew INT;
DECLARE vCurrentItem INT;
DECLARE vQuantity INT;
DECLARE vCounter INT DEFAULT 0;
DECLARE vIsStop BOOL DEFAULT FALSE;
DECLARE vDone BOOL DEFAULT FALSE;
DECLARE curItemClean CURSOR FOR
SELECT GREATEST(i.id, i2.id) idOld,
LEAST(i.id, i2.id) idNew
FROM item i
JOIN (
SELECT i.id,
i.name,
i.subname,
i.value5,
i.value6,
i.value7,
i.value8,
i.value9,
i.value10,
i.NumberOfItemsPerCask,
i.EmbalageCode,
i.quality
FROM item i
LEFT JOIN (
SELECT i.id,
sr.NumberOfUnits,
MAX(di.LatestOrderDateTime) lodt
FROM item i
JOIN edi.supplyResponse sr ON sr.ID = i.supplyResponseFk
JOIN edi.deliveryInformation di ON di.supplyResponseID = i.supplyResponseFk
GROUP BY i.id
)sub ON sub.id = i.id
WHERE i.isFloramondo
AND (i.supplyResponseFk IS NULL
OR sub.NumberOfUnits = 0
OR sub.lodt < util.VN_NOW())
GROUP BY i.name,
i.subname,
i.value5,
i.value6,
i.value7,
i.value8,
i.value9,
i.value10,
i.NumberOfItemsPerCask,
i.EmbalageCode,
i.quality
) i2 ON i2.name <=> i.name
AND i2.subname <=> i.subname
AND i2.value5 <=> i.value5
AND i2.value6 <=> i.value6
AND i2.value7 <=> i.value7
AND i2.value8 <=> i.value8
AND i2.value9 <=> i.value9
AND i2.value10 <=> i.value10
AND i2.NumberOfItemsPerCask <=> i.NumberOfItemsPerCask
AND i2.EmbalageCode <=> i.EmbalageCode
AND i2.quality <=> i.quality
JOIN (
SELECT DISTINCT b.itemFk
FROM buy b
JOIN item i ON i.id = b.itemFk
WHERE i.isFloramondo
AND NOT b.printedStickers
)sub2 ON sub2.itemFk = GREATEST(i.id, i2.id)
WHERE i.isFloramondo
AND i.id <> i2.id;
DECLARE EXIT HANDLER FOR SQLEXCEPTION SET vDone = TRUE;
BEGIN
SET vDone = TRUE;
ROLLBACK;
RESIGNAL;
END;
SET @isModeInventory:= TRUE;
OPEN curItemClean;
curItemClean: LOOP
FETCH curItemClean INTO vItemOld, vItemNew;
START TRANSACTION;
# Deletes
UPDATE IGNORE itemCost
SET itemFk = vItemNew
WHERE itemFk = vItemOld;
DELETE FROM itemCost
WHERE itemFk = vItemOld;
DELETE FROM bs.waste
WHERE itemFk = vItemOld;
DELETE FROM priceFixed
WHERE itemFk = vItemOld;
DELETE FROM itemMatchProperties
WHERE itemFk = vItemOld;
DELETE FROM itemBotanical
WHERE itemFk = vItemOld;
DELETE FROM itemProposal
WHERE itemFk = vItemOld;
SET @isTriggerDisabled := TRUE;
DELETE FROM itemTag
WHERE itemFk = vItemOld;
SET @isTriggerDisabled := FALSE;
DELETE FROM itemBarcode
WHERE itemFk = vItemOld;
DELETE FROM itemTaxCountry
WHERE itemFk = vItemOld;
# Updates
UPDATE buy
SET itemFk = vItemNew
WHERE itemFk = vItemOld;
UPDATE sale
SET itemFk = vItemNew
WHERE itemFk = vItemOld;
UPDATE specialPrice
SET itemFk = vItemNew
WHERE itemFk = vItemOld;
UPDATE packaging
SET itemFk = vItemNew
WHERE itemFk = vItemOld;
UPDATE packaging
SET freightItemFk = vItemNew
WHERE freightItemFk = vItemOld;
UPDATE hedera.orderRow
SET itemFk = vItemNew
WHERE itemFk = vItemOld;
UPDATE itemLog
SET originFk = vItemNew
WHERE originFk = vItemOld;
UPDATE itemShelving
SET itemFk = vItemNew
WHERE itemFk = vItemOld;
UPDATE ticketPackagingStartingStock
SET itemFk = vItemNew
WHERE itemFk = vItemOld;
UPDATE inventoryFailure
SET itemFk = vItemNew
WHERE itemFk = vItemOld;
UPDATE genericAllocation
SET itemFk = vItemNew
WHERE itemFk = vItemOld;
UPDATE itemPlacementSupply
SET itemFk = vItemNew
WHERE itemFk = vItemOld;
# Mantenemos la imagen si el nuevo no tiene
UPDATE vn.item itemNew
LEFT JOIN item itemOld ON itemOld.id = vItemOld
AND itemOld.image IS NOT NULL
SET itemNew.image = itemOld.image
WHERE itemNew.id = vItemNew
AND itemNew.image IS NULL;
# Eliminamos el item sustituido
DELETE FROM item
WHERE id = vItemOld;
COMMIT;
SET vCounter = vCounter + 1;
END LOOP;
CLOSE curItemClean;
SET @isModeInventory:= FALSE;
END$$
DELIMITER ;