85 lines
3.3 KiB
SQL
85 lines
3.3 KiB
SQL
DELIMITER $$
|
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`item_getSimilar`(vItemFk INT, vWarehouseFk INT, vDate DATE, vIsShowedByType BOOL)
|
|
BEGIN
|
|
|
|
/**
|
|
* Propone articulos similares para posible cambio,
|
|
* ordenado con la cantidad de veces usado y segun sus caracteristicas
|
|
*
|
|
* @param vItemFk item id
|
|
* @param vWarehouseFk warehouse id
|
|
* @param vDate fecha para revisar disponible
|
|
* @param vIsShowedByType para mostrar solo artículos de ese tipo
|
|
*/
|
|
|
|
DECLARE vCalcFk INT;
|
|
DECLARE vTypeFk INT;
|
|
|
|
DECLARE vTag1 VARCHAR(25) CHARACTER SET 'utf8' COLLATE 'utf8_unicode_ci';
|
|
DECLARE vTag5 VARCHAR(25) CHARACTER SET 'utf8' COLLATE 'utf8_unicode_ci';
|
|
DECLARE vTag6 VARCHAR(25) CHARACTER SET 'utf8' COLLATE 'utf8_unicode_ci';
|
|
DECLARE vTag7 VARCHAR(25) CHARACTER SET 'utf8' COLLATE 'utf8_unicode_ci';
|
|
DECLARE vTag8 VARCHAR(25) CHARACTER SET 'utf8' COLLATE 'utf8_unicode_ci';
|
|
|
|
DECLARE vValue1 VARCHAR(50) CHARACTER SET 'utf8' COLLATE 'utf8_unicode_ci';
|
|
DECLARE vValue5 VARCHAR(50) CHARACTER SET 'utf8' COLLATE 'utf8_unicode_ci';
|
|
DECLARE vValue6 VARCHAR(50) CHARACTER SET 'utf8' COLLATE 'utf8_unicode_ci';
|
|
DECLARE vValue7 VARCHAR(50) CHARACTER SET 'utf8' COLLATE 'utf8_unicode_ci';
|
|
DECLARE vValue8 VARCHAR(50) CHARACTER SET 'utf8' COLLATE 'utf8_unicode_ci';
|
|
|
|
|
|
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, vDate);
|
|
|
|
SELECT i.id itemFk,
|
|
i.longName,
|
|
i.subName,
|
|
i.tag5,
|
|
i.value5,
|
|
(i.value5 <=> vValue5) match5,
|
|
i.tag6,
|
|
i.value6,
|
|
(i.value6 <=> vValue6) match6,
|
|
i.tag7,
|
|
i.value7,
|
|
(i.value7 <=> vValue7) match7,
|
|
i.tag8,
|
|
i.value8,
|
|
(i.value8 <=> vValue8) match8,
|
|
a.available,
|
|
IFNULL(ip.counter,0) counter,
|
|
IF(b.groupingMode = 1, b.grouping, b.packing) as minQuantity
|
|
FROM vn.item i
|
|
JOIN cache.available a ON a.item_id = i.id
|
|
LEFT JOIN vn.itemProposal ip ON ip.mateFk = i.id AND ip.itemFk = vItemFk
|
|
LEFT JOIN vn.itemTag it1 ON it1.itemFk = i.id AND it1.priority = 1
|
|
LEFT JOIN vn.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 vn.buy b ON b.id = lb.buy_id
|
|
WHERE a.calc_id = vCalcFk
|
|
AND available > 0
|
|
AND IF(vIsShowedByType, i.typeFk = vTypeFk, TRUE)
|
|
AND i.id != vItemFk
|
|
ORDER BY counter DESC,
|
|
(t1.name = vTag1) DESC,
|
|
(it1.value = vValue1) DESC,
|
|
(i.tag6 = vTag6) DESC,
|
|
(i.value6 = vValue6) DESC,
|
|
(i.tag5 = vTag5) DESC,
|
|
(i.value5 = vValue5) DESC,
|
|
(i.tag7 = vTag7) DESC,
|
|
(i.value7 = vValue7) DESC,
|
|
(i.tag8 = vTag8) DESC,
|
|
(i.value8 = vValue8) DESC
|
|
LIMIT 30;
|
|
|
|
|
|
END$$
|
|
DELIMITER ;
|