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

147 lines
4.5 KiB
MySQL
Raw Normal View History

DELIMITER $$
2024-08-20 08:06:10 +00:00
CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`collectionPlacement_get`(
vParamFk INT(11),
vIsPicker bool)
BEGIN
/**
* Devuelve el listado de ubicaciones a las que hay que ir
* para preparar una colección o ticket de manera ordenada
*
* @param vParamFk Identificador de collection o Identificador de ticket
* @param vIsPicker Booleano para distinguer el sacador del revisador
*/
DECLARE vCalcFk INT;
DECLARE vWarehouseFk INT;
DECLARE vCurrentYear INT DEFAULT YEAR(util.VN_NOW());
CREATE OR REPLACE TEMPORARY TABLE tSale
(INDEX(ticketFk), INDEX(saleFk), INDEX(itemFk))
ENGINE = MEMORY
SELECT s.ticketFk, s.id saleFk, s.itemFk, s.quantity
FROM ticketCollection tc
JOIN sale s ON s.ticketFk = tc.ticketFk
WHERE tc.collectionFk = vParamFk
UNION ALL
SELECT s.ticketFk, s.id, s.itemFk, s.quantity
FROM sale s
WHERE s.ticketFk = vParamFk;
SELECT t.warehouseFk
INTO vWarehouseFk
FROM ticket t
JOIN tSale ts ON ts.ticketFk = t.id
JOIN warehouse w ON w.id = t.warehouseFk
LIMIT 1;
CALL cache.visible_refresh(vCalcFk, FALSE, vWarehouseFk);
CREATE OR REPLACE TEMPORARY TABLE tGrouping
(INDEX(itemFk))
ENGINE = MEMORY
SELECT b.itemFk,
CASE b.groupingMode
WHEN NULL THEN 1
WHEN 'packing' THEN b.packing
ELSE b.`grouping`
END `grouping`
FROM buy b
JOIN cache.last_buy lb ON lb.buy_id = b.id
WHERE lb.warehouse_id = vWarehouseFk
GROUP BY b.itemFk;
CREATE OR REPLACE TEMPORARY TABLE tSalePlacementList
(INDEX(saleFk), INDEX(`order`))
ENGINE = MEMORY
SELECT ts.saleFk,
ts.itemFk,
CAST(0 AS DECIMAL(10,0)) saleOrder,
2024-09-30 06:25:40 +00:00
(IF(ish.visible > 0 OR iss.id, 1, 100000) *
COALESCE(p2.pickingOrder, p.pickingOrder)) `order`,
TO_SECONDS(COALESCE(iss.created, ish.created)) - TO_SECONDS(MAKEDATE(IFNULL(YEAR(iss.created), YEAR(ish.created)), 1)) priority,
CONCAT(
2024-09-30 06:25:40 +00:00
IF(iss.id, CONCAT('< ', COALESCE(wk.`code`, '---'),' > '), ''),
p.`code`
) COLLATE utf8_general_ci placement,
sh.priority shelvingPriority,
sh.code COLLATE utf8_general_ci shelving,
ish.created,
ish.visible,
2024-09-30 06:25:40 +00:00
COALESCE(
IF(st.code = 'previousByPacking', ish.packing, g.`grouping`),1) `grouping`,
(st.code = 'previousPrepared') isPreviousPrepared,
iss.id itemShelvingSaleFk,
ts.ticketFk,
iss.id,
st.saleFk salePreviousPrepared,
iss.userFk,
ts.quantity
FROM tSale ts
2024-09-30 06:25:40 +00:00
LEFT JOIN (SELECT st.saleFk
FROM saleTracking st
JOIN state s ON s.id = st.stateFk
WHERE st.isChecked
AND s.semaphore = 1) st ON st.saleFk = ts.saleFk
JOIN itemShelving ish ON ish.itemFk = ts.itemFk
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
JOIN warehouse w ON w.id = sc.warehouseFk
LEFT JOIN tGrouping g ON g.itemFk = ts.itemFk
LEFT JOIN itemShelvingSale iss ON iss.saleFk = ts.saleFk
2024-09-30 06:25:40 +00:00
AND iss.itemShelvingFk = ish.id
LEFT JOIN worker wk ON wk.id = iss.userFk
LEFT JOIN saleGroupDetail sgd ON sgd.saleFk = ts.saleFk
LEFT JOIN saleGroup sg ON sg.id = sgd.saleGroupFk
LEFT JOIN parking p2 ON p2.id = sg.parkingFk
WHERE w.id = vWarehouseFk
2024-09-30 06:25:40 +00:00
AND NOT sc.isHideForPickers
AND ((iss.id IS NOT NULL AND st.saleFk IS NOT NULL) OR st.saleFk IS NULL);
CREATE OR REPLACE TEMPORARY TABLE tSalePlacementList2
(INDEX(saleFk), INDEX(olderPriority))
ENGINE = MEMORY
SELECT saleFk, priority olderPriority
FROM (SELECT saleFk, priority
FROM tSalePlacementList
ORDER BY isPreviousPrepared DESC,
itemShelvingSaleFk IS NULL DESC,
visible >= quantity DESC,
visible > 0 DESC,
IFNULL(shelvingPriority, 0) DESC,
priority
LIMIT 10000000000000000000
)sub
GROUP BY saleFk;
UPDATE tSalePlacementList tsp
JOIN (SELECT s1.saleFk, `order` saleOrder
FROM tSalePlacementList s1
JOIN tSalePlacementList2 s2 ON s2.saleFk = s1.saleFk
AND s2.olderPriority = s1.priority
) sub ON sub.saleFk = tsp.saleFk
SET tsp.saleOrder = sub.saleOrder;
-- Anula el orden de antigüedad y ordena por ubicación
UPDATE tSalePlacementList
SET saleOrder = `order`;
SELECT spl.*
FROM tSalePlacementList spl
JOIN sale s ON s.id = spl.saleFk
ORDER BY saleOrder,
isPreviousPrepared DESC,
itemShelvingSaleFk DESC,
IF(vIsPicker, visible = 0, TRUE),
s.quantity <= spl.visible DESC,
shelvingPriority DESC,
priority;
DROP TEMPORARY TABLE
tSale,
tGrouping,
tSalePlacementList,
tSalePlacementList2;
END$$
DELIMITER ;