salix/db/routines/vn/procedures/workerWeekControl.sql

134 lines
5.9 KiB
MySQL
Raw Normal View History

DELIMITER $$
2024-08-20 08:06:10 +00:00
CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`workerWeekControl`(vUserFk INT, vDated DATE, vTabletFk VARCHAR(100))
BEGIN
/*
* Devuelve la cantidad de descansos de 12h y de 36 horas que ha disfrutado el trabajador
* en la semana inmediatamente anterior a la fecha que pasa como parámetro.
* UPDATED PAK 2019/09/02
* PENDING REVIEW
*/
DECLARE vDescansos12h INT;
DECLARE vDescansos36h INT;
DECLARE vJornadas INT;
DECLARE vImpares INT;
DECLARE vHasSignedToday BOOLEAN;
DECLARE v12hoursInMinutes INT DEFAULT 719;
DECLARE v36hoursInMinutes INT DEFAULT 2159;
DECLARE vCantWork VARCHAR(50) DEFAULT '';
DECLARE vDepartmentFk INT;
DECLARE isEnabled BOOLEAN DEFAULT TRUE;
SELECT COUNT(*) INTO vHasSignedToday
FROM workerTimeControl WHERE timed >= vDated AND userFk = vUserFk;
SET @day := 0;
SET @lastTimed := util.VN_NOW();
SELECT SUM(IF(interval_in_minutes >= v12hoursInMinutes,1,0)), SUM(FLOOR(interval_in_minutes/ v36hoursInMinutes)) , SUM(jornadas)
INTO vDescansos12h, vDescansos36h, vJornadas
FROM
(
SELECT fichada_anterior, fichada_actual, interval_in_minutes, jornadas
FROM
(
SELECT @lastTimed fichada_anterior,
timed,
CAST(time_to_sec(timediff(timed,@lastTimed )) / 60 AS UNSIGNED) as interval_in_minutes,
IF(day(timed) != @day, 1, 0) as jornadas,
@day := day(timed) dia_del_mes,
@lastTimed := timed fichada_actual
FROM
(
SELECT day(timed) as dayNumber, dayname(timed) as dayName, timed
FROM
(SELECT TIMESTAMPADD(DAY, -11, util.VN_NOW()) as timed, vUserFk as userFk -- Fichada virtual para los en los que no se ha trabajado la semana anterior
UNION ALL
SELECT timed, userFk
FROM vn.workerTimeControl wtc
WHERE userFk = vUserFk
AND timed >= TIMESTAMPADD(DAY, -10,vDated)
UNION ALL
SELECT IF(vHasSignedToday, '2000-01-01 00:00', util.VN_NOW()) as timed, vUserFk
) sub4
ORDER BY timed
) sub
) sub2
WHERE fichada_actual >= TIMESTAMPADD(WEEK, -1, vDated)
) sub3 ;
SELECT IFNULL(SUM(impar),0) into vImpares
FROM (
SELECT day(timed) as dayNumber,
count(*) mod 2 as impar
FROM vn.workerTimeControl wtc
WHERE userFk = vUserFk
AND timed >= TIMESTAMPADD(WEEK, -1,vDated) AND timed < vDated
GROUP BY dayNumber
) sub;
-- Vacaciones
SELECT at2.name INTO vCantWork
FROM calendar c
JOIN business b ON b.id = c.businessFk
JOIN absenceType at2 ON at2.id = c.dayOffTypeFk
WHERE c.dated = util.VN_CURDATE()
AND at2.isAllowedToWork = FALSE
AND b.workerFk = vUserFk
LIMIT 1;
-- Contrato en vigor
SELECT IF(COUNT(*),vCantWork,'Sin contrato') INTO vCantWork
FROM business b
WHERE b.workerFk = vUserFk
AND b.started <= vDated
AND IFNULL(b.ended, vDated) >= vDated;
-- Departamento si vTabletFk es 0 no hacemos comprobacion (Madrid y Vilassar)
IF vTabletFk <> '0' THEN
-- 1 Obtener el departamento del usuario
SELECT wtcu.departmentFk INTO vDepartmentFk
FROM workerTimeControlUserInfo wtcu
WHERE wtcu.userFk = vUserFk;
-- 2 Comprobar si la tablet pertenece al departamento
SELECT COUNT(td.tabletFk) INTO isEnabled
FROM tabletDepartment td
WHERE td.tabletFk = vTabletFk AND td.departmentFk = vDepartmentFk;
END IF;
IF vJornadas IS NOT NULL THEN
SELECT 'Jornadas' as Item, vJornadas as Cantidad, 'Correcto' AS Análisis
UNION ALL
SELECT 'Descansos 12 h' as Item, vDescansos12h as Cantidad, IF(vDescansos12h >= vJornadas, 'Correcto','Error: 1 por jornada') as Análisis
UNION ALL
SELECT 'Descansos 36 h' as Item, vDescansos36h as Cantidad, IF(vDescansos36h / 2 >= FLOOR(vJornadas/10), 'Correcto','Error: mínimo 2 cada 14 dias') as Análisis
UNION ALL
SELECT 'Dias con fichadas impares' as Item, vImpares as Cantidad, IF(vImpares = 0, 'Correcto','Error') as Análisis
UNION ALL
SELECT IF (LENGTH(vCantWork),CONCAT('Dia no laborable: ', vCantWork),'Dia laborable') as Item,
'' as Cantidad,
IF(LENGTH(vCantWork),'Error', 'Correcto') as Análisis
UNION ALL
SELECT 'El fichador no pertenece a tu departamento.' as Item, '' as Cantidad, IF(isEnabled, 'Correcto','Error') as Análisis;
ELSE
SELECT 'Jornadas' as Item, vJornadas as Cantidad, 'Correcto' AS Análisis
UNION ALL
SELECT 'Descansos 12 h' as Item, vDescansos12h as Cantidad, 'Correcto' as Análisis
UNION ALL
SELECT 'Descansos 36 h' as Item, vDescansos36h as Cantidad, 'Correcto' as Análisis
UNION ALL
SELECT 'Dias con fichadas impares' as Item, vImpares as Cantidad, 'Correcto' as Análisis
UNION ALL
SELECT IF (LENGTH(vCantWork),CONCAT('Dia no laborable: ', vCantWork),'Dia laborable') as Item,
'' as Cantidad, IF(LENGTH(vCantWork),'Error', 'Correcto') as Análisis
UNION ALL
SELECT 'El fichador no pertenece a tu departamento.' as Item, '' as Cantidad, IF(isEnabled, 'Correcto','Error') as Análisis;
END IF;
END$$
DELIMITER ;