117 lines
3.1 KiB
SQL
117 lines
3.1 KiB
SQL
DELIMITER $$
|
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`item_getSimilar`(
|
|
vSelf INT,
|
|
vTicketFk INT,
|
|
vShowType BOOL
|
|
)
|
|
BEGIN
|
|
/**
|
|
* Propone articulos disponibles ordenados, con la cantidad
|
|
* de veces usado y segun sus caracteristicas.
|
|
*
|
|
* @param vSelf Id de artículo
|
|
* @param vTicketFk Id de ticket
|
|
* @param vShowType Mostrar tipos
|
|
*/
|
|
DECLARE vWarehouseFk INT;
|
|
DECLARE vShipped DATE;
|
|
DECLARE vCalcFk INT;
|
|
DECLARE vTypeFk INT;
|
|
DECLARE vPriority INT DEFAULT 1;
|
|
|
|
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 warehouseFk, shipped
|
|
INTO vWarehouseFk, vShipped
|
|
FROM ticket
|
|
WHERE id = vTicketFk;
|
|
|
|
SELECT typeFk,
|
|
tag5,
|
|
value5,
|
|
tag6,
|
|
value6,
|
|
tag7,
|
|
value7,
|
|
tag8,
|
|
value8,
|
|
t.name,
|
|
it.value
|
|
INTO vTypeFk,
|
|
vTag5,
|
|
vValue5,
|
|
vTag6,
|
|
vValue6,
|
|
vTag7,
|
|
vValue7,
|
|
vTag8,
|
|
vValue8,
|
|
vTag1,
|
|
vValue1
|
|
FROM item i
|
|
LEFT JOIN itemTag it ON it.itemFk = i.id
|
|
AND it.priority = vPriority
|
|
LEFT JOIN tag t ON t.id = it.tagFk
|
|
WHERE i.id = vSelf;
|
|
|
|
CALL cache.available_refresh(vCalcFk, FALSE, vWarehouseFk, vShipped);
|
|
|
|
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) 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 = vSelf
|
|
LEFT JOIN itemTag it ON it.itemFk = i.id
|
|
AND it.priority = vPriority
|
|
LEFT JOIN tag t ON t.id = it.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 a.available > 0
|
|
AND IF(vShowType, i.typeFk = vTypeFk, TRUE)
|
|
AND i.id <> vSelf
|
|
ORDER BY `counter` DESC,
|
|
(t.name = vTag1) DESC,
|
|
(it.value = vValue1) DESC,
|
|
(i.tag5 = vTag5) DESC,
|
|
match5 DESC,
|
|
(i.tag6 = vTag6) DESC,
|
|
match6 DESC,
|
|
(i.tag7 = vTag7) DESC,
|
|
match7 DESC,
|
|
(i.tag8 = vTag8) DESC,
|
|
match8 DESC;
|
|
END$$
|
|
DELIMITER ;
|