100 lines
3.5 KiB
MySQL
100 lines
3.5 KiB
MySQL
|
DELIMITER $$
|
||
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `bs`.`workerProductivity_add`()
|
||
|
BEGIN
|
||
|
DECLARE vDateFrom DATE;
|
||
|
SELECT DATE_SUB(util.VN_CURDATE(),INTERVAL 30 DAY) INTO vDateFrom;
|
||
|
|
||
|
DELETE FROM workerProductivity
|
||
|
WHERE dated >= vDateFrom;
|
||
|
|
||
|
-- SACADORES Y ARTIFICIAL
|
||
|
INSERT INTO workerProductivity(dated, wareHouseFk, workerFk, volume, seconds, stateFk)
|
||
|
SELECT sub.dated,
|
||
|
sub.warehouseFk,
|
||
|
sub.workerFk,
|
||
|
SUM(sub.volume),
|
||
|
SUM(sub.seconds),
|
||
|
sub.stateFk
|
||
|
FROM(SELECT t.warehouseFk warehouseFk,
|
||
|
st.workerFk,
|
||
|
DATE(t.shipped) dated,
|
||
|
SUM((ic.cm3delivery * s.quantity)/1000000) volume,
|
||
|
TIME_TO_SEC(TIMEDIFF( MAX(st.created),MIN(st.created))) + wc.minSeconsItemPicker seconds,
|
||
|
s2.id stateFk
|
||
|
FROM vn.saleTracking st
|
||
|
LEFT JOIN vn.salesPreviousPreparated sp ON sp.saleFk = st.saleFk
|
||
|
JOIN vn.sale s ON s.id = st.saleFk
|
||
|
JOIN vn.ticket t ON t.id = s.ticketFk
|
||
|
JOIN vn.itemCost ic ON ic.warehouseFk = t.warehouseFk AND ic.itemFk = s.itemFk
|
||
|
JOIN vn.worker w ON w.id = st.workerFk
|
||
|
JOIN vn.state s2 ON s2.id = st.stateFk
|
||
|
LEFT JOIN vn.workerDepartment wd ON wd.workerFk = st.workerFk
|
||
|
JOIN workerProductivityConfig wc ON TRUE
|
||
|
WHERE t.shipped >= vDateFrom
|
||
|
AND ISNULL(sp.saleFk)
|
||
|
AND (s2.code IN ('OK PREVIOUS', 'PREVIOUS_PREPARATION', 'PREPARED', 'OK'))
|
||
|
GROUP BY t.id, t.warehouseFk, st.workerFk
|
||
|
) sub
|
||
|
GROUP BY sub.warehouseFk, sub.workerFk, sub.dated;
|
||
|
|
||
|
-- ENCAJADORES
|
||
|
INSERT INTO workerProductivity(dated, wareHouseFk, workerFk, volume, seconds, stateFk)
|
||
|
SELECT sub2.shipped,
|
||
|
sub2.warehouseFk,
|
||
|
sub2.workerFK,
|
||
|
SUM(sub2.volume),
|
||
|
SUM(sub2.seconds),
|
||
|
s2.id stateFk
|
||
|
FROM (SELECT t.warehouseFk,
|
||
|
SUM(s.volume) volume,
|
||
|
sub.workerFk,
|
||
|
DATE(t.shipped) shipped,
|
||
|
sub.seconds + w.minSeconsPackager seconds,
|
||
|
s.saleFk
|
||
|
FROM vn.saleVolume s
|
||
|
JOIN vn.ticket t ON t.id = s.ticketFk
|
||
|
JOIN(SELECT e.workerFk, e.ticketFk,TIME_TO_SEC(TIMEDIFF( MAX(e.created), MIN(e.created))) seconds
|
||
|
FROM vn.expedition e
|
||
|
JOIN vn.ticket t ON t.id = e.ticketFk
|
||
|
WHERE e.workerFk IS NOT NULL AND
|
||
|
t.shipped >= vDateFrom
|
||
|
GROUP BY e.ticketFk
|
||
|
)sub ON sub.ticketFk = t.id
|
||
|
JOIN workerProductivityConfig w ON TRUE
|
||
|
GROUP BY s.ticketFk, t.warehouseFk
|
||
|
)sub2
|
||
|
JOIN vn.state s2 ON s2.code IN ('PACKING','PACKED')
|
||
|
GROUP BY sub2.warehouseFk,sub2.workerFk, sub2.shipped;
|
||
|
|
||
|
-- REVISADORES
|
||
|
INSERT INTO workerProductivity(dated, wareHouseFk, workerFk, volume, seconds, stateFk)
|
||
|
SELECT sub2.shipped,
|
||
|
sub2.warehouseFk,
|
||
|
sub2.workerFK,
|
||
|
SUM(sub2.volume),
|
||
|
SUM(sub2.seconds),
|
||
|
sub2.stateFk
|
||
|
FROM (SELECT t.warehouseFk,
|
||
|
SUM(s.volume) volume,
|
||
|
sub.workerFk,
|
||
|
DATE(t.shipped) shipped,
|
||
|
sub.seconds + w.minSeconsPackager seconds,
|
||
|
sub.stateFk
|
||
|
FROM vn.saleVolume s
|
||
|
JOIN vn.ticket t ON t.id = s.ticketFk
|
||
|
JOIN(SELECT st.workerFk, t.id ticketFk,TIME_TO_SEC(TIMEDIFF( MAX(st.created), MIN(st.created))) seconds, s2.id stateFk
|
||
|
FROM vn.saleTracking st
|
||
|
JOIN vn.state s2 ON s2.id = st.stateFk
|
||
|
JOIN vn.sale s ON s.id = st.saleFk
|
||
|
JOIN vn.ticket t ON s.ticketFk = t.id
|
||
|
WHERE s2.code = 'CHECKED'
|
||
|
AND t.shipped >= vDateFrom
|
||
|
GROUP BY t.id
|
||
|
)sub ON sub.ticketFk = t.id
|
||
|
JOIN workerProductivityConfig w ON TRUE
|
||
|
GROUP BY s.ticketFk, t.warehouseFk
|
||
|
)sub2
|
||
|
GROUP BY sub2.warehouseFk,sub2.workerFk, sub2.shipped;
|
||
|
END$$
|
||
|
DELIMITER ;
|