DELIMITER $$ CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`workerTimeControl_clockIn`( vWorkerFk INT, vTimed DATETIME, vDirection VARCHAR(10), vDevice VARCHAR(255) ) BEGIN /** * Verifica si el empleado puede fichar * @param vWorkerFk Identificador del trabajador * @param vTimed Balor de la fichada, IF vTimed IS NULL vTimed = NOW * @param vDirection Solo se pueden pasa los valores del campo * workerTimeControl.direction ENUM('in', 'out', 'middle') * @param vDevice Dispositivo en el que se ha fichado * @return Si todo es correcto, retorna el número de id la tabla workerTimeControl. * Si hay algún problema, devuelve el mesaje que se debe mostrar al usuario * Solo retorna el primer problema, en caso de no ocurrir ningún error se añadirá * fichada a la tabla vn.workerTimeControl */ DECLARE vLastIn DATETIME; DECLARE vLastOut DATETIME; DECLARE vNextIn DATETIME; DECLARE vNextOut DATETIME; DECLARE vNextDirection ENUM('in', 'out'); DECLARE vLastDirection ENUM('in', 'out'); DECLARE vDayMaxTime INTEGER; DECLARE vDayBreak INT; DECLARE vShortWeekBreak INT; DECLARE vLongWeekBreak INT; DECLARE vWeekScope INT; DECLARE vMailTo VARCHAR(50) DEFAULT NULL; DECLARE vUserName VARCHAR(50) DEFAULT NULL; DECLARE vIsError BOOLEAN DEFAULT FALSE; DECLARE vErrorMessage VARCHAR(255) DEFAULT NULL; DECLARE vErrorCode VARCHAR(50); DECLARE vDated DATE; DECLARE vIsAllowedToWork VARCHAR(50); DECLARE vIsManual BOOLEAN DEFAULT TRUE; DECLARE vMaxWorkShortCycle INT; DECLARE vMaxWorkLongCycle INT; DECLARE EXIT HANDLER FOR SQLSTATE '45000' BEGIN 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; SELECT `description` INTO vErrorMessage FROM workerTimeControlError WHERE `code` = vErrorCode; IF vErrorMessage IS NULL THEN SET vErrorMessage = 'Error sin definir'; END IF; SELECT vErrorMessage `error`; SELECT CONCAT(vUserName, ' no ha podido fichar por el siguiente problema: ', vErrorMessage) INTO vErrorMessage; CALL mail_insert( vMailTo, vMailTo, 'Error al fichar', vErrorMessage); END; IF (vTimed IS NULL) THEN SET vTimed = util.VN_NOW(); SET vIsManual = FALSE; END IF; SET vDated = DATE(vTimed); SELECT IF(pc.code = 'driverCE', wc.dayBreakDriver, wc.dayBreak), wc.shortWeekBreak, wc.longWeekBreak, wc.weekScope, wc.dayMaxTime, wc.maxWorkShortCycle, wc.maxWorkLongCycle INTO vDayBreak, vShortWeekBreak, vLongWeekBreak, vWeekScope, vDayMaxTime, vMaxWorkShortCycle, vMaxWorkLongCycle FROM business b JOIN professionalCategory pc ON pc.id = b.workerBusinessProfessionalCategoryFk JOIN workerTimeControlConfig wc WHERE b.workerFk = vWorkerFk AND vDated BETWEEN b.started AND IFNULL(b.ended, vDated); -- CONTRATO EN VIGOR IF vDayBreak IS NULL THEN SET vErrorCode = 'INACTIVE_BUSINESS'; CALL util.throw(vErrorCode); END IF; -- FICHADAS A FUTURO IF vTimed > util.VN_NOW() + INTERVAL 1 MINUTE THEN SET vErrorCode = 'IS_NOT_ALLOWED_FUTURE'; CALL util.throw(vErrorCode); END IF; -- VERIFICAR SI ESTÁ PERMITIDO TRABAJAR CALL timeBusiness_calculateByWorker(vWorkerFk, vDated, vDated); SELECT isAllowedToWork INTO vIsAllowedToWork FROM tmp.timeBusinessCalculate; DROP TEMPORARY TABLE tmp.timeBusinessCalculate; IF NOT vIsAllowedToWork THEN SET vErrorCode = 'IS_NOT_ALLOWED_WORK'; CALL util.throw(vErrorCode); END IF; -- DIRECCION CORRECTA CALL workerTimeControl_direction(vWorkerFk, vTimed); IF (SELECT IF(IF(option1 IN ('inMiddle', 'outMiddle'), 'middle', option1) <> vDirection AND IF(option2 IN ('inMiddle', 'outMiddle'), 'middle', IFNULL(option2, '')) <> vDirection, TRUE , FALSE) FROM tmp.workerTimeControlDirection ) THEN SET vIsError = TRUE; END IF; DROP TEMPORARY TABLE tmp.workerTimeControlDirection; IF vIsError THEN SET vErrorCode = 'WRONG_DIRECTION'; CALL util.throw(vErrorCode); END IF; -- FICHADAS IMPARES SELECT timed INTO vLastIn FROM workerTimeControl WHERE userFk = vWorkerFk AND direction = 'in' AND timed < vTimed ORDER BY timed DESC LIMIT 1; IF (SELECT IF(vDirection = 'in', MOD(COUNT(*), 2) , IF (vDirection = 'out', NOT MOD(COUNT(*), 2), FALSE)) FROM workerTimeControl WHERE userFk = vWorkerFk AND timed BETWEEN vLastIn AND vTimed ) THEN SET vErrorCode = 'ODD_WORKERTIMECONTROL'; CALL util.throw(vErrorCode); END IF; -- DESCANSO DIARIO SELECT timed INTO vLastOut FROM workerTimeControl WHERE userFk = vWorkerFk AND direction = 'out' AND timed < vTimed ORDER BY timed DESC LIMIT 1; SELECT timed INTO vNextIn FROM workerTimeControl WHERE userFk = vWorkerFk AND direction = 'in' AND timed > vTimed ORDER BY timed ASC LIMIT 1; CASE vDirection WHEN 'in' THEN IF UNIX_TIMESTAMP(vTimed) - UNIX_TIMESTAMP(vLastOut) <= vDayBreak THEN SET vIsError = TRUE; END IF; WHEN 'out' THEN IF UNIX_TIMESTAMP(vNextIn) - UNIX_TIMESTAMP(vTimed) <= vDayBreak THEN SET vIsError = TRUE; END IF; ELSE BEGIN END; END CASE; IF vIsError THEN SET vErrorCode = 'BREAK_DAY'; CALL util.throw(vErrorCode); END IF; IF (vDirection IN('in', 'out')) THEN -- VERIFICA MAXIMO TIEMPO DESDE ENTRADA HASTA LA SALIDA SELECT timed INTO vNextOut FROM workerTimeControl WHERE userFk = vWorkerFk AND direction = 'out' AND timed > vTimed ORDER BY timed ASC LIMIT 1; SELECT direction INTO vNextDirection FROM workerTimeControl WHERE userFk = vWorkerFk AND direction IN('in','out') AND timed > vTimed ORDER BY timed ASC LIMIT 1; SELECT direction INTO vLastDirection FROM workerTimeControl WHERE userFk = vWorkerFk AND direction IN('in', 'out') AND timed < vTimed ORDER BY timed ASC LIMIT 1; IF (vDirection ='in' AND vNextDirection = 'out' AND UNIX_TIMESTAMP(vNextOut) - UNIX_TIMESTAMP(vTimed) > vDayMaxTime) OR (vDirection ='out' AND vLastDirection = 'in' AND UNIX_TIMESTAMP(vTimed) -UNIX_TIMESTAMP(vLastIn) > vDayMaxTime) THEN SET vErrorCode = 'DAY_MAX_TIME'; CALL util.throw(vErrorCode); END IF; -- VERIFICA DESCANSO SEMANAL WITH wtc AS( (SELECT timed FROM vn.workerTimeControl WHERE userFk = vWorkerFk AND direction IN ('in', 'out') AND timed BETWEEN vTimed - INTERVAL (vWeekScope * 2) SECOND AND vTimed + INTERVAL (vWeekScope * 2) SECOND ) UNION (SELECT vTimed) ), wtcGap AS( SELECT timed, TIMESTAMPDIFF(SECOND, LAG(timed) OVER (ORDER BY timed), timed) gap FROM wtc ORDER BY timed ), wtcBreak AS( SELECT timed, IF(IFNULL(gap, 0) > vShortWeekBreak, TRUE, FALSE) hasShortBreak, IF(IFNULL(gap, 0) > vLongWeekBreak, TRUE, FALSE) hasLongBreak FROM wtcGap ORDER BY timed ), wtcBreakCounter AS( SELECT timed, SUM(hasShortBreak) OVER (ORDER BY timed) breakCounter , LEAD(hasLongBreak) OVER (ORDER BY timed) nextHasLongBreak FROM wtcBreak )SELECT TIMESTAMPDIFF(SECOND, MIN(timed), MAX(timed)) > vMaxWorkLongCycle OR (TIMESTAMPDIFF(SECOND, MIN(timed), MAX(timed))> vMaxWorkShortCycle AND NOT SUM(IFNULL(nextHasLongBreak, 1))) hasError INTO vIsError FROM wtcBreakCounter GROUP BY breakCounter HAVING hasError LIMIT 1; IF vIsError THEN SET vErrorCode = 'BREAK_WEEK'; CALL util.throw(vErrorCode); END IF; END IF; -- Se permite fichar INSERT INTO workerTimeControl(userFk, timed, direction, device, `manual`) VALUES(vWorkerFk, vTimed, vDirection, vDevice, vIsManual); SELECT LAST_INSERT_ID() id; END$$ DELIMITER ;