DELIMITER $$ CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`workerTimeControl_checkBreak`(vStarted DATE) BEGIN /** * Retorna los trabajadores que no han respetado el descanso semanal de 36/72 horas * El sistema verificará el descanso corto en la siguiente semana * o el largo en las 2 siguientes semanas a partir de la fecha dada * @param vStarted día inicio de la semana en el que se quiere verificar * @return tmp.workerWithoutWeekBreak (workerFk) */ DECLARE vShortEnded DATETIME; DECLARE vLongEnded DATETIME; DECLARE vShortWeekBreak INT; DECLARE vLongWeekBreak INT; SELECT util.dayEnd(DATE_ADD(vStarted, INTERVAL shortWeekDays DAY)), util.dayEnd(DATE_ADD(vStarted, INTERVAL longWeekDays DAY)), shortWeekBreak, longWeekBreak INTO vShortEnded, vLongEnded, vShortWeekBreak, vLongWeekBreak FROM workerTimeControlConfig; SET @previousTimed:= UNIX_TIMESTAMP(vStarted); SET @lastUserFk := NULL; -- Descanso corto en la semana DROP TEMPORARY TABLE IF EXISTS tmp.worker; CREATE TEMPORARY TABLE tmp.worker (PRIMARY KEY(workerFk)) ENGINE = MEMORY SELECT DISTINCT userFk workerFk FROM workerTimeControl WHERE timed BETWEEN vStarted AND vShortEnded AND direction IN ('in', 'out'); DROP TEMPORARY TABLE IF EXISTS tmp.worker2; CREATE TEMPORARY TABLE tmp.worker2 (PRIMARY KEY(workerFk)) ENGINE = MEMORY SELECT workerFk FROM tmp.worker; DROP TEMPORARY TABLE IF EXISTS tmp.workerWithoutShortWeekBreak; CREATE TEMPORARY TABLE tmp.workerWithoutShortWeekBreak SELECT sub2.userFk workerFk FROM(SELECT sub.userFk, IF(sub.userFk <> @lastUserFk, @previousTimed:= sub.timed, FALSE), IF(sub.timed - @previousTimed >= vShortWeekBreak, TRUE, FALSE) hasShortWeekBreak, @previousTimed:= sub.timed, @lastUserFk:= sub.userFk FROM ( SELECT userFk, UNIX_TIMESTAMP(timed) timed FROM workerTimeControl WHERE timed BETWEEN vStarted AND vShortEnded AND direction IN ('in', 'out') UNION SELECT w.workerFk, UNIX_TIMESTAMP(IFNULL( MIN(wtc.timed), DATE_ADD(vShortEnded, INTERVAL vShortWeekBreak SECOND))) FROM tmp.worker w LEFT JOIN workerTimeControl wtc ON wtc.userFk = w.workerFk AND wtc.timed BETWEEN vShortEnded AND DATE_ADD(vShortEnded, INTERVAL vShortWeekBreak SECOND) GROUP BY w.workerFk UNION SELECT w.workerFk, UNIX_TIMESTAMP(IFNULL( MAX(wtc.timed), DATE_SUB(vStarted, INTERVAL vShortWeekBreak SECOND))) FROM tmp.worker2 w LEFT JOIN workerTimeControl wtc ON wtc.userFk = w.workerFk AND wtc.timed BETWEEN DATE_SUB(vStarted, INTERVAL vShortWeekBreak SECOND) AND vStarted GROUP BY w.workerFk ORDER BY userFk, timed LIMIT 10000000000000000000 )sub )sub2 GROUP BY sub2.userFk HAVING NOT SUM(hasShortWeekBreak); -- Descanso largo en las 2 siguientes semanas DROP TEMPORARY TABLE tmp.worker; CREATE TEMPORARY TABLE tmp.worker (PRIMARY KEY(workerFk)) ENGINE = MEMORY SELECT workerFk FROM tmp.workerWithoutShortWeekBreak; DROP TEMPORARY TABLE tmp.worker2; CREATE TEMPORARY TABLE tmp.worker2 (PRIMARY KEY(workerFk)) ENGINE = MEMORY SELECT workerFk FROM tmp.workerWithoutShortWeekBreak; DROP TEMPORARY TABLE IF EXISTS tmp.workerWithoutWeekBreak; CREATE TEMPORARY TABLE tmp.workerWithoutWeekBreak (PRIMARY KEY(workerFk)) ENGINE = MEMORY SELECT sub2.userFk workerFk FROM(SELECT userFk, IF(userFk <> @lastUserFk, @previousTimed:= timed, TRUE), IF(timed - @previousTimed >= vLongWeekBreak, TRUE, FALSE) hasLongWeekBreak, @previousTimed:= timed, @lastUserFk:= userFk FROM (SELECT userFk, UNIX_TIMESTAMP(timed) timed FROM workerTimeControl wtc JOIN tmp.workerWithoutShortWeekBreak wws ON wws.workerFk = wtc.userFk WHERE timed BETWEEN vStarted AND vLongEnded AND direction IN ('in', 'out') UNION SELECT w.workerFk, UNIX_TIMESTAMP(IFNULL(MIN(wtc.timed), DATE_ADD(vLongEnded, INTERVAL vLongWeekBreak SECOND))) FROM tmp.worker w LEFT JOIN workerTimeControl wtc ON wtc.userFk = w.workerFk AND timed BETWEEN vLongEnded AND DATE_ADD(vLongEnded, INTERVAL vLongWeekBreak SECOND) GROUP BY w.workerFk UNION SELECT w.workerFk, UNIX_TIMESTAMP(IFNULL(MAX(wtc.timed), DATE_SUB(vStarted, INTERVAL vLongWeekBreak SECOND))) FROM tmp.worker2 w LEFT JOIN workerTimeControl wtc ON wtc.userFk = w.workerFk AND timed BETWEEN DATE_SUB(vStarted, INTERVAL vLongWeekBreak SECOND) AND vStarted GROUP BY w.workerFk ORDER BY userFk, timed LIMIT 10000000000000000000 )sub )sub2 GROUP BY userFk HAVING NOT SUM(hasLongWeekBreak); DROP TEMPORARY TABLE tmp.workerWithoutShortWeekBreak, tmp.worker, tmp.worker2; END$$ DELIMITER ;