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

88 lines
2.8 KiB
MySQL
Raw Normal View History

DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`itemProposal`(vItemFk INT, vTicketFk INT,vShowType BOOL)
BEGIN
/**
* Propone articulos disponible ordenado, con la cantidad de veces usado y segun sus caracteristicas
*
* @param vItemFk item id
* @param vTicketFk ticket id
* @param vShowType mostrar tipos
*/
DECLARE vWarehouseFk INT;
DECLARE vShipped DATE;
DECLARE vCalcFk INT;
DECLARE vTypeFk INT;
DECLARE vTag1 VARCHAR(25);
DECLARE vTag5 VARCHAR(25);
DECLARE vTag6 VARCHAR(25);
DECLARE vTag7 VARCHAR(25);
DECLARE vTag8 VARCHAR(25);
DECLARE vValue1 VARCHAR(50);
DECLARE vValue5 VARCHAR(50);
DECLARE vValue6 VARCHAR(50);
DECLARE vValue7 VARCHAR(50);
DECLARE vValue8 VARCHAR(50);
SELECT warehouseFk, shipped INTO vWarehouseFk, vShipped
FROM vn.ticket
WHERE id = vTicketFk;
SELECT typeFk, tag5, value5, tag6, value6, tag7, value7, tag8, value8, t1.name, it1.value
INTO vTypeFk, vTag5, vValue5, vTag6, vValue6, vTag7, vValue7, vTag8, vValue8, vTag1, vValue1
FROM vn.item i
LEFT JOIN vn.itemTag it1 ON it1.itemFk = i.id AND it1.priority = 1
LEFT JOIN vn.tag t1 ON t1.id = it1.tagFk
WHERE i.id = vItemFk;
CALL cache.available_refresh(vCalcFk, FALSE, vWarehouseFk, vShipped);
SELECT i.id itemFk,
i.longName,
i.subName,
i.tag5,
i.value5,
(i.value5 <=> vValue5 COLLATE utf8_general_ci) match5,
i.tag6,
i.value6,
(i.value6 <=> vValue6 COLLATE utf8_general_ci) match6,
i.tag7,
i.value7,
(i.value7 <=> vValue7 COLLATE utf8_general_ci) match7,
i.tag8,
i.value8,
(i.value8 <=> vValue8 COLLATE utf8_general_ci) match8,
a.available,
IFNULL(ip.counter,0) counter,
IF(b.groupingMode = 1, b.grouping, b.packing) as minQuantity,
iss.visible located
FROM item i
JOIN cache.available a ON a.item_id = i.id
LEFT JOIN itemProposal ip ON ip.mateFk = i.id AND ip.itemFk = vItemFk
LEFT JOIN itemTag it1 ON it1.itemFk = i.id AND it1.priority = 1
LEFT JOIN tag t1 ON t1.id = it1.tagFk
LEFT JOIN cache.last_buy lb ON lb.item_id = i.id AND lb.warehouse_id = vWarehouseFk
LEFT JOIN buy b ON b.id = lb.buy_id
LEFT JOIN itemShelvingStock iss ON iss.itemFk = i.id AND iss.warehouseFk = vWarehouseFk
WHERE a.calc_id = vCalcFk
AND available > 0
AND IF(vShowType,i.typeFk = vTypeFk,true)
AND i.id != vItemFk
ORDER BY counter DESC,
(t1.name = vTag1 COLLATE utf8_general_ci) DESC,
(it1.value = vValue1 COLLATE utf8_general_ci) DESC,
(i.tag5 = vTag5 COLLATE utf8_general_ci) DESC,
(i.value5 = vValue5 COLLATE utf8_general_ci) DESC,
(i.tag6 = vTag6 COLLATE utf8_general_ci) DESC,
(i.value6 = vValue6 COLLATE utf8_general_ci) DESC,
(i.tag7 = vTag7 COLLATE utf8_general_ci) DESC,
(i.value7 = vValue7 COLLATE utf8_general_ci) DESC,
(i.tag8 = vTag8 COLLATE utf8_general_ci) DESC,
(i.value8 = vValue8 COLLATE utf8_general_ci) DESC;
END$$
DELIMITER ;