DELIMITER $$ CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`productionControl`( vWarehouseFk INT, vScopeDays INT ) proc: BEGIN /** * Devuelve un listado de tickets con parámetros relativos a la producción de los días en rango. * * @param vWarehouseFk Identificador de warehouse * @param vScopeDays Número de días desde hoy en adelante que entran en el cálculo. * * @return Table tmp.productionBuffer */ DECLARE vEndingDate DATETIME; DECLARE vIsTodayRelative BOOLEAN; SELECT util.dayEnd(util.VN_CURDATE()) + INTERVAL LEAST(vScopeDays, maxProductionScopeDays) DAY INTO vEndingDate FROM productionConfig; SELECT isTodayRelative INTO vIsTodayRelative FROM worker WHERE id = getUser(); -- Cambiar por account.myUser_getId(), falta dar permisos CALL prepareTicketList(util.yesterday(), vEndingDate); CREATE OR REPLACE TEMPORARY TABLE tmp.ticket SELECT * FROM tmp.productionTicket; CALL prepareClientList(); CREATE OR REPLACE TEMPORARY TABLE tmp.sale_getProblems (INDEX (ticketFk)) ENGINE = MEMORY SELECT tt.ticketFk, tt.clientFk, t.warehouseFk, t.shipped FROM tmp.productionTicket tt JOIN ticket t ON t.id = tt.ticketFk; CALL ticket_getProblems(vIsTodayRelative); CREATE OR REPLACE TEMPORARY TABLE tmp.productionBuffer (PRIMARY KEY(ticketFk), previaParking VARCHAR(255)) ENGINE = MEMORY SELECT tt.ticketFk, tt.clientFk, t.warehouseFk, t.nickname, t.packages, IF(HOUR(t.shipped), HOUR(t.shipped), COALESCE(HOUR(zc.hour),HOUR(z.hour))) HH, COALESCE(HOUR(zc.hour), HOUR(z.hour)) Departure, COALESCE(MINUTE(t.shipped), MINUTE(zc.hour), MINUTE(z.hour)) mm, t.routeFk, IF(dm.code = 'DELIVERY', z.`id`, 0) zona, t.nickname addressNickname, a.postalCode, a.city, p.name province, CONCAT(z.`name`,' ',IFNULL(RIGHT(t.routeFk,3),'')) agency, am.id agencyModeFk, 0 `lines`, CAST( 0 AS DECIMAL(5,2)) m3, CAST( 0 AS DECIMAL(5,2)) preparationRate, "" problem, IFNULL(tls.state,2) state, w.code workerCode, DATE(t.shipped) shipped, wk.code salesPersonCode, p.id provinceFk, tls.productionOrder, IFNULL(tls.alertLevel, al.id) alertLevel, t.isBoxed palletized, IF(rm.isPickingAllowed, rm.bufferFk, NULL) ubicacion, tlu.lastUpdated, IFNULL(st.graphCategory, 0) graphCategory, pk.code parking, 0 H, 0 V, 0 N, st.isOk, ag.isOwn, rm.bufferFk FROM tmp.productionTicket tt JOIN ticket t ON tt.ticketFk = t.id JOIN alertLevel al ON al.code = 'FREE' LEFT JOIN ticketStateToday tst ON tst.ticketFk = t.id LEFT JOIN `state` st ON st.id = tst.state LEFT JOIN client c ON c.id = t.clientFk LEFT JOIN worker wk ON wk.id = c.salesPersonFk JOIN address a ON a.id = t.addressFk LEFT JOIN province p ON p.id = a.provinceFk JOIN agencyMode am ON am.id = t.agencyModeFk JOIN deliveryMethod dm ON dm.id = am.deliveryMethodFk JOIN agency ag ON ag.id = am.agencyFk LEFT JOIN ticketState tls ON tls.ticketFk = tt.ticketFk LEFT JOIN ticketLastUpdated tlu ON tlu.ticketFk = tt.ticketFk LEFT JOIN worker w ON w.id = tls.userFk LEFT JOIN routesMonitor rm ON rm.routeFk = t.routeFk LEFT JOIN `zone` z ON z.id = t.zoneFk LEFT JOIN zoneClosure zc ON zc.zoneFk = t.zoneFk AND DATE(t.shipped) = zc.dated LEFT JOIN ticketParking tp ON tp.ticketFk = t.id LEFT JOIN parking pk ON pk.id = tp.parkingFk WHERE t.warehouseFk = vWarehouseFk AND dm.code IN ('AGENCY', 'DELIVERY', 'PICKUP'); UPDATE tmp.productionBuffer pb JOIN ( SELECT pb.ticketFk, GROUP_CONCAT(p.code) previaParking FROM tmp.productionBuffer pb JOIN sale s ON s.ticketFk = pb.ticketFk JOIN saleGroupDetail sgd ON sgd.saleFk = s.id JOIN saleGroup sg ON sg.id = sgd.saleGroupFk JOIN parking p ON p.id = sg.parkingFk GROUP BY pb.ticketFk ) t ON t.ticketFk = pb.ticketFk SET pb.previaParking = t.previaParking; -- Problemas por ticket ALTER TABLE tmp.productionBuffer CHANGE COLUMN `problem` `problem` VARCHAR(255), ADD COLUMN `collectionH` INT, ADD COLUMN `collectionV` INT, ADD COLUMN `collectionN` INT; UPDATE tmp.productionBuffer pb JOIN tmp.ticket_problems tp ON tp.ticketFk = pb.ticketFk SET pb.problem = TRIM(CAST(CONCAT( IFNULL(tp.itemShortage, ''), IFNULL(tp.itemDelay, ''), IFNULL(tp.itemLost, ''), IF(tp.isFreezed, ' CONGELADO',''), IF(tp.hasHighRisk, ' RIESGO',''), IF(tp.hasTicketRequest, ' COD 100',''), IF(tp.isTaxDataChecked, '',' FICHA INCOMPLETA'), IF(tp.hasComponentLack, ' COMPONENTES', ''), IF(HOUR(util.VN_NOW()) < pb.HH AND tp.isTooLittle, ' PEQUEÑO', '') ) AS char(255))); -- Clientes Nuevos o Recuperados UPDATE tmp.productionBuffer pb LEFT JOIN bs.clientNewBorn cnb ON cnb.clientFk = pb.clientFk JOIN productionConfig pc SET pb.problem = TRIM(CAST(CONCAT('NUEVO ', pb.problem) AS CHAR(255))) WHERE (cnb.clientFk IS NULL OR cnb.isRookie) AND pc.rookieDays; -- Líneas y volumen por ticket UPDATE tmp.productionBuffer pb JOIN ( SELECT tt.ticketFk, COUNT(*) `lines`, SUM(s.quantity * ic.cm3delivery / 1000000) m3, IFNULL(SUM(IF(s.isPicked, (s.quantity * ic.cm3delivery / 1000000), 0)) / SUM(s.quantity * ic.cm3delivery / 1000000), 0) rate FROM tmp.productionTicket tt JOIN sale s ON s.ticketFk = tt.ticketFk AND s.quantity > 0 JOIN itemCost ic ON ic.itemFk = s.itemFk AND ic.warehouseFk = vWarehouseFk GROUP BY tt.ticketFk ) m ON m.ticketFk = pb.ticketFk SET pb.`lines` = m.`lines`, pb.m3 = m.m3, pb.preparationRate = m.rate; DELETE FROM tmp.productionBuffer WHERE NOT `lines`; -- Lineas por linea de encajado CREATE OR REPLACE TEMPORARY TABLE tItemPackingType (PRIMARY KEY(ticketFk)) ENGINE = MEMORY SELECT ticketFk, SUM(sub.H) H, SUM(sub.V) V, SUM(sub.N) N FROM ( SELECT t.ticketFk, SUM(i.itemPackingTypeFk = 'H') H, SUM(i.itemPackingTypeFk = 'V') V, SUM(i.itemPackingTypeFk IS NULL) N FROM tmp.productionTicket t JOIN sale s ON s.ticketFk = t.ticketFk JOIN item i ON i.id = s.itemFk GROUP BY t.ticketFk, i.itemPackingTypeFk ) sub GROUP BY ticketFk; UPDATE tmp.productionBuffer pb JOIN tItemPackingType ti ON ti.ticketFk = pb.ticketFk SET pb.H = ti.H, pb.V = ti.V, pb.N = ti.N; -- Colecciones segun tipo de encajado UPDATE tmp.productionBuffer pb JOIN ticketCollection tc ON pb.ticketFk = tc.ticketFk SET pb.collectionH = IF(pb.H, tc.collectionFk, NULL), pb.collectionV = IF(pb.V, tc.collectionFk, NULL), pb.collectionN = IF(pb.N, tc.collectionFk, NULL); -- Previa pendiente ALTER TABLE tmp.productionBuffer ADD previousWithoutParking BOOL DEFAULT FALSE; CREATE OR REPLACE TEMPORARY TABLE tmp.ticketWithPrevia (ticketFk INT PRIMARY KEY, salesCount INT DEFAULT 0, salesInParkingCount INT DEFAULT 0) ENGINE = MEMORY; CREATE OR REPLACE TEMPORARY TABLE tItemShelvingStock (PRIMARY KEY(itemFk, sectorFk)) ENGINE = MEMORY SELECT ish.itemFk, p.sectorFk, st.code = 'previousPrepared' isPreviousPrepared, sc.itemPackingTypeFk FROM itemShelving ish JOIN shelving sh ON sh.code = ish.shelvingFk JOIN parking p ON p.id = sh.parkingFk JOIN sector sc ON sc.id = p.sectorFk JOIN sectorType st ON st.id = sc.typeFk WHERE p.sectorFk AND ish.visible GROUP BY ish.itemFk, p.sectorFk; CREATE INDEX idxItem ON tItemShelvingStock (itemFk); INSERT INTO tmp.ticketWithPrevia(ticketFk, salesCount) SELECT pb.ticketFk, COUNT(DISTINCT s.id) FROM tmp.productionBuffer pb JOIN sale s ON s.ticketFk = pb.ticketFk JOIN tItemShelvingStock iss ON iss.itemFk = s.itemFk JOIN sector sc ON sc.id = iss.sectorFk JOIN item i ON i.id = iss.itemFk WHERE iss.isPreviousPrepared AND (sc.itemPackingTypeFk IS NULL OR (i.itemPackingTypeFk IS NULL AND NOT pb.V) OR sc.itemPackingTypeFk = i.itemPackingTypeFk) AND s.quantity > 0 GROUP BY pb.ticketFk; UPDATE tmp.ticketWithPrevia twp JOIN ( SELECT pb.ticketFk, COUNT(DISTINCT s.id) salesInParkingCount FROM tmp.productionBuffer pb JOIN sale s ON s.ticketFk = pb.ticketFk JOIN saleGroupDetail sgd ON sgd.saleFk = s.id JOIN saleGroup sg ON sg.id = sgd.saleGroupFk WHERE sg.parkingFk IS NOT NULL AND s.quantity > 0 GROUP BY pb.ticketFk ) sub ON twp.ticketFk = sub.ticketFk SET twp.salesInParkingCount = sub.salesInParkingCount; UPDATE tmp.productionBuffer pb JOIN tmp.ticketWithPrevia twp ON twp.ticketFk = pb.ticketFk SET pb.previousWithoutParking = TRUE WHERE twp.salesCount > twp.salesInParkingCount; -- hasPlantTray ALTER TABLE tmp.productionBuffer ADD hasPlantTray BOOL DEFAULT FALSE; UPDATE tmp.productionBuffer pb JOIN sale s ON s.ticketFk = pb.ticketFk JOIN item i ON i.id = s.itemFk JOIN itemType it ON it.id = i.typeFk JOIN itemCategory ic ON ic.id = it.categoryFk JOIN cache.last_buy lb ON lb.warehouse_id = vWarehouseFk AND lb.item_id = s.itemFk JOIN buy b ON b.id = lb.buy_id JOIN packaging p ON p.id = b.packagingFk JOIN productionConfig pc SET hasPlantTray = TRUE WHERE ic.code = 'plant' AND p.`depth` >= pc.minPlantTrayLength; DROP TEMPORARY TABLE tmp.productionTicket, tmp.ticket, tmp.ticket_problems, tmp.ticketWithPrevia, tItemShelvingStock, tItemPackingType; END$$ DELIMITER ;