82 lines
1.7 KiB
SQL
82 lines
1.7 KiB
SQL
DELIMITER $$
|
|
CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`clean_logiflora`()
|
|
BEGIN
|
|
/**
|
|
* Elimina las compras y los artículos residuales de logiflora.
|
|
*/
|
|
DECLARE vDone INT DEFAULT FALSE;
|
|
DECLARE vBuyFk INT;
|
|
DECLARE vItemFk INT;
|
|
|
|
DECLARE cur1 CURSOR FOR SELECT id FROM tBuy;
|
|
DECLARE cur2 CURSOR FOR SELECT id FROM tItem;
|
|
|
|
DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE;
|
|
|
|
DECLARE CONTINUE HANDLER FOR SQLEXCEPTION
|
|
BEGIN
|
|
ROLLBACK;
|
|
RESIGNAL;
|
|
END;
|
|
|
|
CREATE OR REPLACE TEMPORARY TABLE tBuy
|
|
ENGINE = MEMORY
|
|
SELECT b.id
|
|
FROM buy b
|
|
JOIN entry e ON e.id = b.entryFk
|
|
JOIN travel tr ON tr.id = e.travelFk
|
|
JOIN agencyMode am ON am.id = tr.agencyModeFk
|
|
WHERE NOT b.quantity
|
|
AND am.code = 'logiflora'
|
|
AND tr.daysInForward;
|
|
|
|
START TRANSACTION;
|
|
|
|
OPEN cur1;
|
|
read_loop: LOOP
|
|
SET vDone = FALSE;
|
|
FETCH cur1 INTO vBuyFk;
|
|
|
|
IF vDone THEN
|
|
LEAVE read_loop;
|
|
END IF;
|
|
|
|
DELETE FROM buy WHERE id = vBuyFk;
|
|
END LOOP;
|
|
CLOSE cur1;
|
|
|
|
CREATE OR REPLACE TEMPORARY TABLE tItem
|
|
ENGINE = MEMORY
|
|
SELECT DISTINCT i.id
|
|
FROM item i
|
|
LEFT JOIN hedera.orderRow o ON o.itemFk = i.id
|
|
LEFT JOIN sale s ON s.itemFk = i.id
|
|
LEFT JOIN buy b ON b.itemFk = i.id
|
|
LEFT JOIN bs.waste w ON w.itemFk = i.id
|
|
WHERE i.supplyResponseFk
|
|
AND o.id IS NULL
|
|
AND b.id IS NULL
|
|
AND s.id IS NULL
|
|
AND w.itemFk IS NULL
|
|
AND i.created < (util.VN_CURDATE() - INTERVAL (SELECT daysToKeepItem FROM floramondoConfig) DAY);
|
|
|
|
OPEN cur2;
|
|
read_loop: LOOP
|
|
SET vDone = FALSE;
|
|
|
|
FETCH cur2 INTO vItemFk;
|
|
|
|
IF vDone THEN
|
|
LEAVE read_loop;
|
|
END IF;
|
|
|
|
DELETE FROM item WHERE id = vItemFk;
|
|
END LOOP;
|
|
CLOSE cur2;
|
|
|
|
COMMIT;
|
|
|
|
DROP TEMPORARY TABLE tBuy, tItem;
|
|
END$$
|
|
DELIMITER ;
|