salix/db/routines/bs/procedures/workerLabour_getData.sql

107 lines
3.9 KiB
SQL

DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `bs`.`workerLabour_getData`()
BEGIN
/**
* Carga los datos de la plantilla de trabajadores, altas y bajas en la tabla workerLabourDataByMonth para facilitar el cálculo del gráfico en grafana.
* Se carga el día 21 de cada mes, elimina los registros del último año y los vuelve a calcular
*/
DECLARE vFristDay DATE;
DECLARE vLastDay DATE;
DECLARE vDone BOOL DEFAULT FALSE;
DECLARE vDateStarted DATE;
DECLARE vDateEnded DATE;
DECLARE vCursor CURSOR FOR
SELECT util.firstDayOfMonth(t.dated), LAST_DAY(t.dated)
FROM vn.time t
WHERE t.dated BETWEEN vDateStarted AND vDateEnded
GROUP BY year,month;
DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE;
IF DAY(util.VN_CURDATE()) = 21 THEN
SELECT util.firstDayOfMonth(DATE_SUB(util.VN_CURDATE(), INTERVAL 12 MONTH)),
LAST_DAY(DATE_SUB(util.VN_CURDATE(), INTERVAL 1 MONTH))
INTO vDateStarted,
vDateEnded;
DELETE FROM workerLabourDataByMonth
WHERE CONCAT(`year`, '-',`month`, '-01') BETWEEN vDateStarted AND vDateEnded;
OPEN vCursor;
l: LOOP
SET vDone = FALSE;
FETCH vCursor INTO vFristDay, vLastDay;
IF vDone THEN
LEAVE l;
END IF;
-- Altas periodo
INSERT INTO workerLabourDataByMonth (code, month, year, total, permanent)
SELECT 'hiring', MONTH(vFristDay), YEAR(vFristDay), COUNT(*), SUM(wbt.isPermanent)
FROM vn.business b
JOIN vn.workCenter wc ON wc.id = b.workCenterFk
JOIN vn.worker w ON w.id = b.workerFk
LEFT JOIN vn.workerBusinessType wbt ON wbt.id = b.workerBusinessTypeFk
LEFT JOIN (SELECT b.id, b.workerFk
FROM vn.business b
LEFT JOIN (SELECT ended, workerFk FROM vn.business) wl
ON wl.ended = DATE_SUB(b.started, INTERVAL 1 DAY) AND wl.workerFk = b.workerFk
WHERE b.started BETWEEN vFristDay AND vLastDay AND wl.ended
)sub ON sub.workerFk = b.workerFk
WHERE wc.payrollCenterFk IS NOT NULL
AND b.workCenterFk IS NOT NULL
AND b.started BETWEEN vFristDay AND vLastDay
AND sub.workerFk IS NULL
AND NOT w.isFreelance;
-- Bajas periodo
INSERT INTO workerLabourDataByMonth (code, month, year, total, permanent)
SELECT 'layoffs', MONTH(vFristDay), YEAR(vFristDay), COUNT(*), SUM(wbt.isPermanent)
FROM vn.business b
JOIN vn.worker w ON w.id = b.workerFk
JOIN vn.workCenter wc ON wc.id = b.workCenterFk
LEFT JOIN vn.workerBusinessType wbt ON wbt.id = b.workerBusinessTypeFk
LEFT JOIN (SELECT started, workerFk FROM vn.business) wl ON wl.started >= b.ended
AND wl.workerFk = b.workerFk
WHERE wc.payrollCenterFk IS NOT NULL
AND b.ended BETWEEN vFristDay AND vLastDay
AND wl.started IS NULL
AND NOT w.isFreelance;
-- Anterior al periodo
SET vLastDay = LAST_DAY(DATE_SUB(vFristDay, INTERVAL 1 DAY));
INSERT INTO workerLabourDataByMonth (code, month, year, total, permanent)
SELECT 'staff', MONTH(vFristDay), YEAR(vFristDay), COUNT(*), SUM(wbt.isPermanent)
FROM vn.business b
JOIN vn.worker w ON w.id = b.workerFk
JOIN vn.workCenter wc ON wc.id = b.workCenterFk
LEFT JOIN vn.workerBusinessType wbt ON wbt.id = b.workerBusinessTypeFk
WHERE wc.payrollCenterFk IS NOT NULL
AND vLastDay BETWEEN started AND IFNULL(ended, vLastDay)
AND NOT w.isFreelance;
-- Discapacidad
INSERT INTO workerLabourDataByMonth (code, month, year, total, permanent)
SELECT 'disabled', MONTH(vFristDay), YEAR(vFristDay), COUNT(*), SUM(wbt.isPermanent)
FROM vn.business b
JOIN vn.worker w ON w.id = b.workerFk
JOIN vn.workCenter wc ON wc.id = b.workCenterFk
LEFT JOIN vn.workerBusinessType wbt ON wbt.id = b.workerBusinessTypeFk
WHERE wc.payrollCenterFk IS NOT NULL
AND vLastDay BETWEEN started AND IFNULL(ended, vLastDay)
AND w.isDisable
AND NOT w.isFreelance;
END LOOP;
CLOSE vCursor;
END IF;
END$$
DELIMITER ;