77 lines
2.5 KiB
SQL
77 lines
2.5 KiB
SQL
DELIMITER $$
|
|
CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`workerTimeControl_direction`(vWorkerFk VARCHAR(10), vTimed DATETIME)
|
|
BEGIN
|
|
/**
|
|
* Devuelve que direcciones de fichadas son lógicas a partir de la anterior fichada
|
|
* @param vWorkerFk Identificador del trabajador
|
|
* @return (option1, option2)
|
|
* Los valores posibles de retorno son ('in', 'inMiddle', 'outMiddle', 'out')
|
|
*/
|
|
DECLARE vLastIn DATETIME ;
|
|
DECLARE vIsMiddleOdd BOOLEAN ;
|
|
DECLARE vMailTo VARCHAR(50) DEFAULT NULL;
|
|
DECLARE vUserName VARCHAR(50) DEFAULT NULL;
|
|
|
|
IF (vTimed IS NULL) THEN
|
|
SET vTimed = util.VN_NOW();
|
|
END IF;
|
|
|
|
SELECT timed INTO vLastIn
|
|
FROM workerTimeControl
|
|
WHERE userFk = vWorkerFk
|
|
AND direction = 'in'
|
|
AND timed < vTimed
|
|
ORDER BY timed DESC
|
|
LIMIT 1;
|
|
|
|
SELECT (COUNT(*)mod 2 = 1) INTO vIsMiddleOdd
|
|
FROM workerTimeControl
|
|
WHERE userFk = vWorkerFk
|
|
AND direction = 'middle'
|
|
AND timed BETWEEN vLastIn AND vTimed;
|
|
|
|
DROP TEMPORARY TABLE IF EXISTS tmp.workerTimeControlDirection;
|
|
CREATE TEMPORARY TABLE tmp.workerTimeControlDirection
|
|
SELECT IF(isCorrect, option1, NULL) option1,
|
|
IF(isCorrect, option2, NULL) option2
|
|
FROM( SELECT IF(w.direction <> 'out' AND (UNIX_TIMESTAMP(vTimed) - UNIX_TIMESTAMP(w.timed) > wc.dayBreak), FALSE, TRUE) isCorrect,
|
|
CASE WHEN w.direction ='in' THEN 'inMiddle'
|
|
WHEN w.direction = 'out' THEN 'in'
|
|
WHEN w.direction = 'middle' AND vIsMiddleOdd THEN 'outMiddle'
|
|
WHEN w.direction IS NULL THEN 'in'
|
|
ELSE 'inMiddle'
|
|
END option1,
|
|
CASE WHEN w.direction ='in' THEN 'out'
|
|
WHEN w.direction = 'out' THEN NULL
|
|
WHEN w.direction = 'middle' AND vIsMiddleOdd THEN NULL
|
|
WHEN w.direction IS NULL THEN NULL
|
|
ELSE 'out'
|
|
END option2
|
|
FROM workerTimeControl w
|
|
JOIN workerTimeControlConfig wc ON TRUE
|
|
WHERE w.timed <= vTimed
|
|
AND w.userFk = vWorkerFk
|
|
ORDER BY w.timed DESC
|
|
LIMIT 1)sub;
|
|
|
|
IF (SELECT IF(COUNT(*)=0, TRUE, FALSE) FROM tmp.workerTimeControlDirection ) THEN
|
|
INSERT INTO tmp.workerTimeControlDirection (option1, option2)
|
|
VALUES('in', NULL);
|
|
END IF;
|
|
|
|
IF (SELECT option1 IS NULL AND option2 IS NULL FROM tmp.workerTimeControlDirection) THEN
|
|
SELECT CONCAT(u.name, '@verdnatura.es'), CONCAT(w.firstName, ' ', w.lastName)
|
|
INTO vMailTo, vUserName
|
|
FROM account.user u
|
|
JOIN worker w ON w.bossFk = u.id
|
|
WHERE w.id = vWorkerFk;
|
|
|
|
CALL mail_insert(
|
|
vMailTo,
|
|
vMailTo,
|
|
'Error al fichar',
|
|
CONCAT(vUserName, ' tiene problemas para fichar'));
|
|
END IF;
|
|
END$$
|
|
DELIMITER ;
|