salix/db/changes/224701/00-sale_afterUpdate.sql

101 lines
3.2 KiB
SQL

DROP TRIGGER IF EXISTS vn.sale_afterUpdate;
USE vn;
DELIMITER $$
$$
CREATE DEFINER=`root`@`localhost` TRIGGER `vn`.`sale_afterUpdate`
AFTER UPDATE ON `sale`
FOR EACH ROW
BEGIN
DECLARE vIsToSendMail BOOL;
DECLARE vPickedLines INT;
DECLARE vCollectionFk INT;
DECLARE vUserRole VARCHAR(255);
IF !(NEW.id <=> OLD.id)
OR !(NEW.ticketFk <=> OLD.ticketFk)
OR !(NEW.itemFk <=> OLD.itemFk)
OR !(NEW.quantity <=> OLD.quantity)
OR !(NEW.created <=> OLD.created)
OR !(NEW.isPicked <=> OLD.isPicked) THEN
CALL stock.log_add('sale', NEW.id, OLD.id);
END IF;
IF !(NEW.price <=> OLD.price)
OR !(NEW.ticketFk <=> OLD.ticketFk)
OR !(NEW.itemFk <=> OLD.itemFk)
OR !(NEW.quantity <=> OLD.quantity)
OR !(NEW.discount <=> OLD.discount) THEN
CALL ticket_requestRecalc(NEW.ticketFk);
CALL ticket_requestRecalc(OLD.ticketFk);
END IF;
IF !(OLD.ticketFk <=> NEW.ticketFk) THEN
UPDATE ticketRequest SET ticketFk = NEW.ticketFk
WHERE saleFk = NEW.id;
END IF;
SELECT account.myUser_getName() INTO vUserRole;
SELECT account.user_getMysqlRole(vUserRole) INTO vUserRole;
IF !(OLD.quantity <=> NEW.quantity) THEN
SELECT COUNT(*) INTO vIsToSendMail
FROM vncontrol.inter i
JOIN vn.state s ON s.id = i.state_id
WHERE s.code='PACKED'
AND i.Id_Ticket = OLD.ticketFk
AND vUserRole IN ('salesPerson', 'salesTeamBoss')
LIMIT 1;
IF vIsToSendMail THEN
CALL vn.mail_insert('jefesventas@verdnatura.es',
'noreply@verdnatura.es',
CONCAT('Ticket ', OLD.ticketFk ,' modificada cantidad tras encajado'),
CONCAT('Ticket <a href="https://salix.verdnatura.es/#!/ticket/', OLD.ticketFk ,'/log">', OLD.ticketFk ,'</a>. <br>',
'Modificada la catidad de ', OLD.quantity, ' a ' , NEW.quantity,
' del artículo ', OLD.itemFk, ' tras estado encajado del ticket. <br>',
'Este email se ha generado automáticamente' )
);
END IF;
IF (OLD.quantity > NEW.quantity) THEN
INSERT INTO saleComponent(saleFk, componentFk, value)
SELECT NEW.id, cm.id, sc.value
FROM saleComponent sc
JOIN component cd ON cd.id = sc.componentFk
JOIN component cm ON cm.code = 'mana'
WHERE saleFk = NEW.id AND cd.code = 'lastUnitsDiscount'
ON DUPLICATE KEY UPDATE value = sc.value + VALUES(value);
DELETE sc.*
FROM vn.saleComponent sc
JOIN component c ON c.id = sc.componentFk
WHERE saleFk = NEW.id AND c.code = 'lastUnitsDiscount';
END IF;
INSERT IGNORE INTO `vn`.`routeRecalc` (`routeFk`)
SELECT r.id
FROM vn.sale s
JOIN vn.ticket t ON t.id = s.ticketFk
JOIN vn.route r ON r.id = t.routeFk
WHERE r.isOk = FALSE
AND s.id = NEW.id
AND r.created >= CURDATE()
GROUP BY r.id;
END IF;
IF !(ABS(NEW.isPicked) <=> ABS(OLD.isPicked)) AND NEW.quantity > 0 THEN
UPDATE vn.collection c
JOIN vn.ticketCollection tc ON tc.collectionFk = c.id AND tc.ticketFk = NEW.ticketFk
SET c.salePickedCount = c.salePickedCount + IF(NEW.isPicked != 0, 1, -1);
END IF;
IF !(NEW.quantity <=> OLD.quantity) AND (NEW.quantity = 0 OR OLD.quantity = 0) THEN
UPDATE vn.collection c
JOIN vn.ticketCollection tc ON tc.collectionFk = c.id AND tc.ticketFk = NEW.ticketFk
SET c.saleTotalCount = c.saleTotalCount + IF(OLD.quantity = 0, 1, -1);
END IF;
END$$
DELIMITER ;