183 lines
7.6 KiB
SQL
183 lines
7.6 KiB
SQL
|
||
DROP procedure IF EXISTS `vn`.`workerTimeControl_check`;
|
||
|
||
DELIMITER $$
|
||
CREATE DEFINER=`root`@`%` PROCEDURE `vn`.`workerTimeControl_check`(vUserFk INT, vTabletFk VARCHAR(100), vTimed DATETIME)
|
||
BEGIN
|
||
|
||
/**
|
||
* Verifica si el empleado puede fichar en el momento actual, si puede fichar llama a vn.workerTimeControlAdd
|
||
* @param vUserFk Identificador del trabajador
|
||
* @return Retorna si encuentra un problema 'odd','maxTimeWork','breakDay','breakWeek' ;
|
||
* En caso de tener algun problema retorna el primero que encuentra
|
||
*/
|
||
DECLARE vLastIn DATETIME ;
|
||
DECLARE vLastOut DATETIME ;
|
||
DECLARE vDayWorkMax INT;
|
||
DECLARE vDayBreak INT;
|
||
DECLARE vWeekBreak INT ;
|
||
DECLARE vWeekMaxBreak INT;
|
||
DECLARE vWeekScope INT;
|
||
DECLARE vWeekMaxScope INT;
|
||
DECLARE vDayStayMax INT;
|
||
DECLARE vAskInOut INT;
|
||
DECLARE vTimedWorked INT;
|
||
DECLARE vCalendarStateType VARCHAR(20) DEFAULT NULL;
|
||
DECLARE vDepartmentFk INT;
|
||
DECLARE vTo VARCHAR(50) DEFAULT NULL;
|
||
DECLARE vUserName VARCHAR(50) DEFAULT NULL;
|
||
DECLARE vBody VARCHAR(255) DEFAULT NULL;
|
||
|
||
IF (vTimed IS NULL) THEN
|
||
SET vTimed = NOW();
|
||
END IF;
|
||
|
||
SELECT dayBreak, weekBreak, weekScope, dayWorkMax, dayStayMax, weekMaxBreak, weekMaxScope, askInOut
|
||
INTO vDayBreak, vWeekBreak, vWeekScope, vDayWorkMax, vDayStayMax, vWeekMaxBreak, vWeekMaxScope, vAskInOut
|
||
FROM vn.workerTimeControlParams;
|
||
|
||
SELECT MAX(timed) INTO vLastIn
|
||
FROM vn.workerTimeControl
|
||
WHERE userFk = vUserFk AND
|
||
direction = 'in';
|
||
|
||
SELECT MAX(timed) INTO vLastOut
|
||
FROM vn.workerTimeControl
|
||
WHERE userFk = vUserFk AND
|
||
direction = 'out';
|
||
|
||
SELECT email INTO vTo
|
||
FROM vn.worker w
|
||
WHERE w.id = (SELECT bossFk FROM vn.worker WHERE id = vUserFk);
|
||
|
||
SELECT CONCAT(firstName,' ',lastName) INTO vUserName
|
||
FROM vn.worker w
|
||
WHERE w.id = vUserFk;
|
||
|
||
-- VERIFICAR CONTRATO EN VIGOR
|
||
IF (SELECT COUNT(*)
|
||
FROM postgresql.business b
|
||
JOIN postgresql.profile pr ON pr.profile_id = b.client_id
|
||
JOIN postgresql.person p ON p.person_id = pr.person_id
|
||
JOIN vn.worker w ON w.id = p.id_trabajador
|
||
WHERE w.userFk = vUserFk AND
|
||
b.date_start <= CURDATE() AND
|
||
IFNULL(b.date_end,CURDATE()) >= CURDATE()
|
||
) = 0 THEN
|
||
-- ENVIAMOS CORREO AL BOSSFK
|
||
SELECT CONCAT(vUserName,' No ha podido fichar por el siguiente problema: ',"No hay un contrato en vigor") INTO vBody;
|
||
CALL vn.mail_insert(vTo,vTo,'error al fichar',vBody);
|
||
CALL util.throw("No hay un contrato en vigor");
|
||
END IF;
|
||
|
||
-- VERIFICAR DEPARTAMENTO
|
||
IF vTabletFk IS NOT NULL THEN
|
||
IF ( SELECT COUNT(*)
|
||
FROM vn.tabletDepartment td
|
||
JOIN vn.workerTimeControlUserInfo wtcu ON wtcu.departmentFk = td.departmentFk
|
||
WHERE td.tabletFk = vTabletFk AND wtcu.userFk = vUserFk
|
||
) = 0 THEN
|
||
-- ENVIAMOS CORREO AL BOSSFK
|
||
SELECT CONCAT(vUserName,' No ha podido fichar por el siguiente problema: ',"No perteneces a este departamento.") INTO vBody;
|
||
CALL vn.mail_insert(vTo,vTo,'error al fichar',vBody);
|
||
CALL util.throw("No perteneces a este departamento.");
|
||
END IF;
|
||
END IF;
|
||
|
||
SELECT IFNULL(dayBreak, vDayBreak) INTO vDayBreak
|
||
FROM postgresql.business b
|
||
JOIN postgresql.profile pr ON pr.profile_id = b.client_id
|
||
JOIN postgresql.person p ON p.person_id = pr.person_id
|
||
JOIN postgresql. business_labour bl ON b.business_id = bl.business_id
|
||
JOIN postgresql.professional_category pc ON bl.professional_category_id = pc.professional_category_id
|
||
WHERE p.id_trabajador = vUserFk AND
|
||
b.date_start <= DATE(vTimed) AND
|
||
IFNULL(b.date_end, DATE(vTimed)) >= DATE(vTimed);
|
||
-- VERIFICAR DESCANSO DIARIO
|
||
-- 12 / 9 horas dependiendo del valor de vDayBreak
|
||
IF UNIX_TIMESTAMP(vTimed) - UNIX_TIMESTAMP(vLastOut) < vDayBreak THEN
|
||
-- ENVIAMOS CORREO AL BOSSFK
|
||
SELECT CONCAT(vUserName,' No ha podido fichar por el siguiente problema: ',"Descansos ", FORMAT(vDayBreak/3600,0) ," h") INTO vBody;
|
||
CALL vn.mail_insert(vTo,vTo,'error al fichar',vBody);
|
||
CALL util.throw(CONCAT("Descansos ", FORMAT(vDayBreak/3600,0) ," h"));
|
||
END IF;
|
||
|
||
-- VERIFICAR FICHADAS IMPARES DEL ÚLTIMO DÃÂÂA QUE SE FICHÓ
|
||
IF (SELECT MOD(COUNT(*),2) -- <>0
|
||
FROM vn.workerTimeControl
|
||
WHERE userFk = vUserFk AND
|
||
timed >= vLastIn
|
||
) THEN
|
||
-- ENVIAMOS CORREO AL BOSSFK
|
||
SELECT CONCAT(vUserName,' No ha podido fichar por el siguiente problema: ',"Dias con fichadas impares") INTO vBody;
|
||
CALL vn.mail_insert(vTo,vTo,'error al fichar',vBody);
|
||
CALL util.throw("Dias con fichadas impares");
|
||
END IF;
|
||
-- VERIFICAR VACACIONES
|
||
SELECT cs.type INTO vCalendarStateType
|
||
FROM postgresql.calendar_employee ce
|
||
JOIN postgresql.business b USING(business_id)
|
||
JOIN postgresql.profile pr ON pr.profile_id = b.client_id
|
||
JOIN postgresql.person p ON p.person_id = pr.person_id
|
||
JOIN postgresql.calendar_state cs USING(calendar_state_id)
|
||
JOIN vn.worker w ON w.id = p.id_trabajador
|
||
WHERE ce.date = CURDATE() AND
|
||
cs.isAllowedToWork = FALSE AND
|
||
w.userFk = vUserFk
|
||
LIMIT 1;
|
||
|
||
IF(LENGTH(vCalendarStateType)) THEN
|
||
-- ENVIAMOS CORREO AL BOSSFK
|
||
SELECT CONCAT(vUserName,' No ha podido fichar por el siguiente problema: ',"Vacaciones") INTO vBody;
|
||
CALL vn.mail_insert(vTo,vTo,'error al fichar',vBody);
|
||
CALL util.throw(vCalendarStateType);
|
||
END IF;
|
||
|
||
-- VERIFICAR DESCANSO SEMANAL
|
||
SET @vHasBreakWeek:= FALSE;
|
||
SET @vLastTimed:= UNIX_TIMESTAMP((vTimed - INTERVAL vWeekScope SECOND));
|
||
|
||
DROP TEMPORARY TABLE IF EXISTS tmp.trash;
|
||
CREATE TEMPORARY TABLE tmp.trash
|
||
SELECT IF(vWeekBreak-(UNIX_TIMESTAMP(timed)-@vLastTimed) <= 0, @vHasBreakWeek:=TRUE, TRUE) alias,
|
||
@vLastTimed:= UNIX_TIMESTAMP(timed)
|
||
FROM workerTimeControl
|
||
WHERE timed>= (vTimed - INTERVAL vWeekScope SECOND) AND
|
||
userFk= vUserFk AND
|
||
direction IN ('in','out')
|
||
ORDER BY timed ASC;
|
||
|
||
IF UNIX_TIMESTAMP(vTimed) - UNIX_TIMESTAMP(vLastOut) < vWeekBreak AND @vHasBreakWeek = FALSE THEN -- REVISA SI EL DESCANSO SE HA REALIZADO DESPUÉS DE LA ÚLTIMA FICHADA
|
||
SET @vHasBreakWeek:= FALSE;
|
||
SET @vLastTimed:= UNIX_TIMESTAMP((vTimed - INTERVAL vWeekMaxScope SECOND));
|
||
DROP TEMPORARY TABLE tmp.trash;
|
||
CREATE TEMPORARY TABLE tmp.trash
|
||
SELECT IF(vWeekMaxBreak-(UNIX_TIMESTAMP(timed)-@vLastTimed) <= 0, @vHasBreakWeek:=TRUE, TRUE) alias,
|
||
@vLastTimed:= UNIX_TIMESTAMP(timed)
|
||
FROM workerTimeControl
|
||
WHERE timed>= (vTimed - INTERVAL vWeekMaxScope SECOND) AND
|
||
userFk= vUserFk AND
|
||
direction IN ('in','out')
|
||
ORDER BY timed ASC;
|
||
IF UNIX_TIMESTAMP(vTimed) - UNIX_TIMESTAMP(vLastOut) < vWeekMaxBreak AND @vHasBreakWeek = FALSE THEN -- REVISA SI EL DESCANSO SE HA REALIZADO DESPUÉS DE LA ÚLTIMA FICHADA
|
||
-- ENVIAMOS CORREO AL BOSSFK
|
||
SELECT CONCAT(vUserName,' No ha podido fichar por el siguiente problema: ',"Descansos ", FORMAT(vWeekMaxBreak/3600,0) ," h") INTO vBody;
|
||
CALL vn.mail_insert(vTo,vTo,'error al fichar',vBody);
|
||
CALL util.throw(CONCAT( "Descansos ", FORMAT(vWeekMaxBreak/3600,0) ," h"));
|
||
END IF;
|
||
-- ENVIAMOS CORREO AL BOSSFK
|
||
SELECT CONCAT(vUserName,' No ha podido fichar por el siguiente problema: ',"Descansos ", FORMAT(vWeekBreak/3600,0) ," h") INTO vBody;
|
||
CALL vn.mail_insert(vTo,vTo,'error al fichar',vBody);
|
||
CALL util.warn(CONCAT( "Descansos ", FORMAT(vWeekBreak/3600,0) ," h"));
|
||
END IF;
|
||
DROP TEMPORARY TABLE tmp.trash;
|
||
|
||
-- Preguntar dirección de la fichada
|
||
IF UNIX_TIMESTAMP(vTimed) - UNIX_TIMESTAMP(vLastIn) >= vAskInOut AND (SELECT MOD(COUNT(*),2)
|
||
FROM vn.workerTimeControl WHERE userFk = vUserFk AND timed >= vLastIn) THEN
|
||
CALL util.warn("AskInOut");
|
||
END IF ;
|
||
END$$
|
||
|
||
DELIMITER ;
|