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

165 lines
5.5 KiB
MySQL
Raw Normal View History

DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`productionError_add`()
BEGIN
DECLARE vDatedFrom DATETIME;
DECLARE vDatedTo DATETIME;
/**
* Rellena la tabla vn.productionError con estadisticas de encajadores, revisores y sacadores. Se ejecuta en el nightTask
*/
SELECT util.VN_CURDATE() - INTERVAL 1 DAY, util.dayend(util.VN_CURDATE() - INTERVAL 1 DAY) INTO vDatedFrom, vDatedTo;
CALL timeControl_calculateAll(vDatedFrom, vDatedTo);
-- Rellena la tabla tmp.errorsByClaim con encajadores, revisores y sacadores
CREATE OR REPLACE TEMPORARY TABLE tmp.errorsByClaim
ENGINE = MEMORY
SELECT COUNT(c.ticketFk) errors,
cd.workerFk
FROM claimDevelopment cd
JOIN claim c ON cd.claimFk = c.id
JOIN ticket t ON c.ticketFk = t.id
JOIN claimResponsible cr ON cd.claimResponsibleFk = cr.id
WHERE t.shipped BETWEEN vDatedFrom AND vDatedTo
AND cr.code IN ('pic', 'chk', 'pck')
GROUP BY cd.workerFk;
-- Genera la tabla tmp.volume con encajadores, sacadores y revisores
CREATE OR REPLACE TEMPORARY TABLE tmp.volume
ENGINE = MEMORY
SELECT SUM(w.volume) volume,
w.workerFk
FROM bs.workerProductivity w
WHERE w.dated BETWEEN vDatedFrom AND vDatedTo
GROUP BY w.workerFk;
-- Rellena la tabla tmp.errorsByChecker con fallos de revisores
CREATE OR REPLACE TEMPORARY TABLE tmp.errorsByChecker
ENGINE = MEMORY
2024-03-26 07:52:01 +00:00
WITH rankedWorkers AS (
SELECT sm.id,
st.workerFk,
ROW_NUMBER() OVER(PARTITION BY sm.id ORDER BY s2.`order`) AS rnk
FROM saleMistake sm
JOIN saleTracking st ON sm.saleFk = st.saleFk
JOIN `state` s2 ON s2.id = st.stateFk
JOIN sale s ON s.id = sm.saleFk
JOIN ticket t ON t.id = s.ticketFk
WHERE t.shipped BETWEEN vDatedFrom AND vDatedTo
AND s2.code IN ('OK', 'PREVIOUS_PREPARATION', 'PREPARED', 'CHECKED')
)
SELECT workerFk, COUNT(*) AS errors
FROM rankedWorkers
WHERE rnk = 1
GROUP BY workerFk;
-- Rellena la tabla tmp.expeditionErrors con fallos de expediciones
CREATE OR REPLACE TEMPORARY TABLE tmp.expeditionErrors
ENGINE = MEMORY
SELECT COUNT(t.id) errors,
e.workerFk
FROM vn.expeditionMistake pm
JOIN vn.expedition e ON e.id = pm.expeditionFk
JOIN vn.ticket t ON t.id = e.ticketFk
WHERE t.shipped BETWEEN vDatedFrom AND vDatedTo
GROUP BY e.workerFk;
-- Genera la tabla tmp.total para sacadores y revisores
CREATE OR REPLACE TEMPORARY TABLE tmp.total
ENGINE = MEMORY
SELECT st.workerFk,
COUNT(DISTINCT t.id) ticketCount,
COUNT(s.id) lineCount
FROM saleTracking st
JOIN `state` s2 ON s2.id = st.stateFk
JOIN sale s ON s.id = st.saleFk
JOIN ticket t ON s.ticketFk = t.id
WHERE (t.shipped BETWEEN vDatedFrom AND vDatedTo)
AND s2.code IN ('OK','PREVIOUS_PREPARATION','PREPARED','CHECKED')
GROUP BY st.workerFk;
-- Rellena la tabla vn.productionError con sacadores
INSERT INTO productionError(userFk,
firstname,
lastname,
rol,
ticketNumber,
lineNumber,
error,
volume,
hourStart,
hourEnd,
hourWorked,
dated)
SELECT w.id,
w.firstName,
w.lastName,
"Sacadores",
t.ticketCount totalTickets,
t.lineCount,
IFNULL(ec.errors,0) + IFNULL(ec2.errors,0) errors,
v.volume volume,
SUBSTRING(tc.tableTimed, 1, 5) hourStart,
SUBSTRING(tc.tableTimed, LENGTH(tc.tableTimed)-4, 5) hourEnd,
IFNULL(CAST(tc.timeWorkDecimal AS DECIMAL (10,2)) , 0) hourWorked,
vDatedFrom dated
FROM tmp.total t
LEFT JOIN worker w ON w.id = t.workerFk
LEFT JOIN tmp.timeControlCalculate tc ON tc.userFk = t.workerFk
LEFT JOIN tmp.errorsByClaim ec ON ec.workerFk = t.workerFk
LEFT JOIN tmp.volume v ON v.workerFk = t.workerFk
LEFT JOIN tmp.errorsByChecker ec2 ON ec2.workerFk = t.workerFk
JOIN (SELECT DISTINCT w.id -- Verificamos que son sacadores
FROM vn.collection c
JOIN vn.state s ON s.id = c.stateFk
JOIN vn.train tn ON tn.id = c.trainFk
JOIN vn.worker w ON w.id = c.workerFk
WHERE c.created BETWEEN vDatedFrom AND vDatedTo) sub ON sub.id = w.id
GROUP BY w.id;
CREATE OR REPLACE TEMPORARY TABLE itemPickerErrors -- Errores de los sacadores, derivadores de los revisadores
ENGINE = MEMORY
SELECT COUNT(c.ticketFk) errors,
tt.userFk
FROM claimDevelopment cd
JOIN claim c ON cd.claimFk = c.id
JOIN ticket t ON c.ticketFk = t.id
JOIN claimResponsible cr ON cd.claimResponsibleFk = cr.id
JOIN ticketTracking tt ON tt.ticketFk = t.id
JOIN `state` s ON s.id = tt.stateFk
WHERE t.shipped BETWEEN vDatedFrom AND vDatedTo
AND cr.code = 'chk'
AND s.code = 'ON_PREPARATION'
GROUP BY tt.userFk;
UPDATE productionError ep
JOIN itemPickerErrors ipe ON ipe.userFk = ep.userFk
SET ep.error = ep.error + ipe.errors
WHERE vDatedFrom = ep.dated AND ep.rol = 'Sacadores';
DROP TEMPORARY TABLE itemPickerErrors;
-- Rellena la tabla vn.productionError con revisores
CALL productionError_addCheckerPackager(vDatedFrom, vDatedTo, "Revisadores");
-- Genera la tabla tmp.total para encajadores
CREATE OR REPLACE TEMPORARY TABLE tmp.total
ENGINE = MEMORY
SELECT e.workerFk,
COUNT(DISTINCT t.id) ticketCount,
COUNT(s.id) lineCount
FROM expedition e
JOIN ticket t ON e.ticketFk = t.id
JOIN sale s ON s.ticketFk = t.id
WHERE t.shipped BETWEEN vDatedFrom AND vDatedTo
GROUP BY e.workerFk;
-- Rellena la tabla vn.productionError con encajadores
CALL productionError_addCheckerPackager(vDatedFrom, vDatedTo, "Encajadores");
DROP TEMPORARY TABLE tmp.errorsByClaim,
tmp.volume,
tmp.errorsByChecker,
tmp.expeditionErrors,
tmp.total;
END$$
DELIMITER ;