118 lines
3.5 KiB
SQL
118 lines
3.5 KiB
SQL
DELIMITER $$
|
|
CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`item_getSimilar`(
|
|
vSelf INT,
|
|
vWarehouseFk INT,
|
|
vDated DATE,
|
|
vShowType BOOL,
|
|
vDaysInForward INT
|
|
)
|
|
BEGIN
|
|
/**
|
|
* Propone articulos ordenados, con la cantidad
|
|
* de veces usado y segun sus caracteristicas.
|
|
*
|
|
* @param vSelf Id de artículo
|
|
* @param vWarehouseFk Id de almacen
|
|
* @param vDated Fecha
|
|
* @param vShowType Mostrar tipos
|
|
* @param vDaysInForward Días de alcance para las ventas
|
|
*/
|
|
DECLARE vAvailableCalcFk INT;
|
|
DECLARE vPriority INT DEFAULT 1;
|
|
|
|
CALL cache.available_refresh(vAvailableCalcFk, FALSE, vWarehouseFk, vDated);
|
|
|
|
WITH itemTags AS (
|
|
SELECT i.id,
|
|
typeFk,
|
|
tag5,
|
|
value5,
|
|
tag6,
|
|
value6,
|
|
tag7,
|
|
value7,
|
|
tag8,
|
|
value8,
|
|
t.name,
|
|
it.value
|
|
FROM vn.item i
|
|
LEFT JOIN vn.itemTag it ON it.itemFk = i.id
|
|
AND it.priority = vPriority
|
|
LEFT JOIN vn.tag t ON t.id = it.tagFk
|
|
WHERE i.id = vSelf
|
|
),
|
|
stock AS (
|
|
SELECT itemFk, SUM(visible) stock
|
|
FROM vn.itemShelvingStock
|
|
WHERE warehouseFk = vWarehouseFk
|
|
GROUP BY itemFk
|
|
),
|
|
sold AS (
|
|
SELECT SUM(s.quantity) AS quantity,
|
|
s.itemFk
|
|
FROM vn.sale s
|
|
JOIN vn.ticket t ON t.id = s.ticketFk
|
|
LEFT JOIN vn.itemShelvingSale iss ON iss.saleFk = s.id
|
|
WHERE t.shipped BETWEEN CURDATE() AND CURDATE() + INTERVAL vDaysInForward DAY
|
|
AND iss.saleFk IS NULL
|
|
AND t.warehouseFk = vWarehouseFk
|
|
GROUP BY s.itemFk
|
|
)
|
|
SELECT i.id itemFk,
|
|
CAST(sd.quantity AS INT) advanceable,
|
|
i.longName,
|
|
i.subName,
|
|
i.tag5,
|
|
i.value5,
|
|
(i.value5 <=> its.value5) match5,
|
|
i.tag6,
|
|
i.value6,
|
|
(i.value6 <=> its.value6) match6,
|
|
i.tag7,
|
|
i.value7,
|
|
(i.value7 <=> its.value7) match7,
|
|
i.tag8,
|
|
i.value8,
|
|
(i.value8 <=> its.value8) match8,
|
|
a.available,
|
|
IFNULL(ip.counter, 0) `counter`,
|
|
CASE
|
|
WHEN b.groupingMode = 'grouping' THEN b.grouping
|
|
WHEN b.groupingMode = 'packing' THEN b.packing
|
|
ELSE 1
|
|
END minQuantity,
|
|
sk.stock located,
|
|
b.price2
|
|
FROM vn.item i
|
|
LEFT JOIN sold sd ON sd.itemFk = i.id
|
|
JOIN cache.available a ON a.item_id = i.id
|
|
AND a.calc_id = vAvailableCalcFk
|
|
LEFT JOIN stock sk ON sk.itemFk = i.id
|
|
LEFT JOIN cache.last_buy lb ON lb.item_id = i.id
|
|
AND lb.warehouse_id = vWarehouseFk
|
|
LEFT JOIN vn.itemProposal ip ON ip.mateFk = i.id
|
|
AND ip.itemFk = vSelf
|
|
LEFT JOIN vn.itemTag it ON it.itemFk = i.id
|
|
AND it.priority = vPriority
|
|
LEFT JOIN vn.tag t ON t.id = it.tagFk
|
|
LEFT JOIN vn.buy b ON b.id = lb.buy_id
|
|
JOIN itemTags its
|
|
WHERE (a.available > 0 OR sd.quantity < sk.stock)
|
|
AND (i.typeFk = its.typeFk OR NOT vShowType)
|
|
AND i.id <> vSelf
|
|
ORDER BY (a.available > 0) DESC,
|
|
`counter` DESC,
|
|
(t.name = its.name) DESC,
|
|
(it.value = its.value) DESC,
|
|
(i.tag5 = its.tag5) DESC,
|
|
match5 DESC,
|
|
(i.tag6 = its.tag6) DESC,
|
|
match6 DESC,
|
|
(i.tag7 = its.tag7) DESC,
|
|
match7 DESC,
|
|
(i.tag8 = its.tag8) DESC,
|
|
match8 DESC
|
|
LIMIT 100;
|
|
END$$
|
|
DELIMITER ;
|