From 56e6a7e6aa794b2ce7c6ddf58b789622abee4ded Mon Sep 17 00:00:00 2001 From: jgallego Date: Wed, 11 Sep 2024 08:10:21 +0200 Subject: [PATCH 1/4] feat: refs #7956 parametro daysInForward --- db/routines/vn/procedures/item_getSimilar.sql | 186 ++++++++++-------- 1 file changed, 102 insertions(+), 84 deletions(-) diff --git a/db/routines/vn/procedures/item_getSimilar.sql b/db/routines/vn/procedures/item_getSimilar.sql index 823625b97..5c1cfe0e3 100644 --- a/db/routines/vn/procedures/item_getSimilar.sql +++ b/db/routines/vn/procedures/item_getSimilar.sql @@ -1,99 +1,117 @@ DELIMITER $$ -CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`item_getSimilar`( - vSelf INT, - vWarehouseFk INT, - vDated DATE, - vShowType BOOL +CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`item_getSimilar`( + vSelf INT, + vWarehouseFk INT, + vDated DATE, + vShowType BOOL, + vDaysInForward INT ) BEGIN /** -* Propone articulos disponibles ordenados, con la cantidad +* 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 vVisibleCalcFk INT; - DECLARE vTypeFk INT; - DECLARE vPriority INT DEFAULT 1; + DECLARE vAvailableCalcFk INT; + DECLARE vPriority INT DEFAULT 1; - CALL cache.available_refresh(vAvailableCalcFk, FALSE, vWarehouseFk, vDated); - CALL cache.visible_refresh(vVisibleCalcFk, FALSE, vWarehouseFk); + 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 - ) - SELECT i.id itemFk, - 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, - v.visible located, - b.price2 - FROM vn.item i - JOIN cache.available a ON a.item_id = i.id - AND a.calc_id = vAvailableCalcFk - LEFT JOIN cache.visible v ON v.item_id = i.id - AND v.calc_id = vVisibleCalcFk - 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 - AND (i.typeFk = its.typeFk OR NOT vShowType) - AND i.id <> vSelf - ORDER BY `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; + 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 ; -- 2.40.1 From 6ae15a8e649fbcfbec4c04b98e10dabc0db6847f Mon Sep 17 00:00:00 2001 From: jgallego Date: Wed, 11 Sep 2024 08:13:28 +0200 Subject: [PATCH 2/4] feat: refs #7956 definer --- db/routines/vn/procedures/item_getSimilar.sql | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/db/routines/vn/procedures/item_getSimilar.sql b/db/routines/vn/procedures/item_getSimilar.sql index 5c1cfe0e3..bc7c6fa87 100644 --- a/db/routines/vn/procedures/item_getSimilar.sql +++ b/db/routines/vn/procedures/item_getSimilar.sql @@ -1,5 +1,5 @@ DELIMITER $$ -CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`item_getSimilar`( +CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`item_getSimilar`( vSelf INT, vWarehouseFk INT, vDated DATE, -- 2.40.1 From ed8cf628a5ee758af4e4d70bcc193eb8805f462e Mon Sep 17 00:00:00 2001 From: jgallego Date: Wed, 11 Sep 2024 08:15:32 +0200 Subject: [PATCH 3/4] feat: refs #7956 tabulaciones --- db/routines/vn/procedures/item_getSimilar.sql | 141 +++++++++--------- 1 file changed, 70 insertions(+), 71 deletions(-) diff --git a/db/routines/vn/procedures/item_getSimilar.sql b/db/routines/vn/procedures/item_getSimilar.sql index bc7c6fa87..77a21eb83 100644 --- a/db/routines/vn/procedures/item_getSimilar.sql +++ b/db/routines/vn/procedures/item_getSimilar.sql @@ -35,83 +35,82 @@ BEGIN 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 + 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 + 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 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; + 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 ; -- 2.40.1 From 10f75835871dd02b999baa1fa4b1265fa66a2a94 Mon Sep 17 00:00:00 2001 From: jgallego Date: Wed, 11 Sep 2024 11:22:22 +0200 Subject: [PATCH 4/4] feat: refs #7956 sin AS --- db/routines/vn/procedures/item_getSimilar.sql | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/db/routines/vn/procedures/item_getSimilar.sql b/db/routines/vn/procedures/item_getSimilar.sql index 77a21eb83..b524e30a7 100644 --- a/db/routines/vn/procedures/item_getSimilar.sql +++ b/db/routines/vn/procedures/item_getSimilar.sql @@ -48,7 +48,7 @@ BEGIN GROUP BY itemFk ), sold AS ( - SELECT SUM(s.quantity) AS quantity, s.itemFk + SELECT SUM(s.quantity) 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 -- 2.40.1