73 lines
1.7 KiB
SQL
73 lines
1.7 KiB
SQL
DELIMITER $$
|
|
CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`travel_moveRaids`()
|
|
BEGIN
|
|
|
|
/*
|
|
* Desplaza al dia siguiente los travels que contengan redadas y avisa a los compradores
|
|
*
|
|
*/
|
|
DECLARE vDone BOOL DEFAULT FALSE;
|
|
DECLARE vWorkerName VARCHAR(50);
|
|
DECLARE vRaid TEXT;
|
|
DECLARE vWorker VARCHAR(50) DEFAULT '';
|
|
DECLARE vMailBody TEXT DEFAULT '';
|
|
|
|
DECLARE vCur CURSOR FOR
|
|
SELECT GROUP_CONCAT( DISTINCT CONCAT('https://salix.verdnatura.es/#!/travel/', ttr.id, '/summary ') ORDER BY ttr.id SEPARATOR '\n\r'),
|
|
u.name
|
|
FROM tmp.travel ttr
|
|
JOIN entry e ON e.travelFk = ttr.id
|
|
JOIN buy b ON b.entryFk = e.id
|
|
JOIN item i ON i.id = b.itemFk
|
|
JOIN itemType it ON it.id = i.typeFk
|
|
JOIN account.user u ON u.id = it.workerFk
|
|
GROUP BY u.name;
|
|
|
|
DECLARE CONTINUE HANDLER FOR NOT FOUND
|
|
SET vDone = TRUE;
|
|
|
|
DECLARE EXIT HANDLER FOR SQLEXCEPTION
|
|
BEGIN
|
|
ROLLBACK;
|
|
RESIGNAL;
|
|
END;
|
|
|
|
DROP TEMPORARY TABLE IF EXISTS tmp.travel;
|
|
CREATE TEMPORARY TABLE tmp.travel
|
|
SELECT tr.id,tr.landed
|
|
FROM travel tr
|
|
JOIN entry e ON e.travelFk = tr.id
|
|
WHERE tr.landed = util.tomorrow()
|
|
AND e.isRaid
|
|
GROUP BY tr.id;
|
|
|
|
START TRANSACTION;
|
|
|
|
UPDATE travel tr
|
|
JOIN tmp.travel ttr ON ttr.id = tr.id
|
|
SET tr.landed = TIMESTAMPADD(DAY, 1, tr.landed);
|
|
|
|
OPEN vCur;
|
|
|
|
l: LOOP
|
|
SET vDone = FALSE;
|
|
FETCH vCur INTO vRaid, vWorkerName;
|
|
|
|
IF vDone THEN
|
|
LEAVE l;
|
|
END IF;
|
|
|
|
CALL `vn`.`mail_insert`(CONCAT(vWorkerName, '@verdnatura.es'),
|
|
'noreply@verdnatura.es',
|
|
'Cambio de fecha en Redadas',
|
|
CONCAT('Se ha movido las siguientes redadas: \n\r ', vRaid)
|
|
);
|
|
|
|
END LOOP;
|
|
CLOSE vCur;
|
|
COMMIT;
|
|
DROP TEMPORARY TABLE tmp.travel;
|
|
|
|
END$$
|
|
DELIMITER ;
|