Merge pull request 'refactor: refs #7440 itemComparativeOptimization' (!2501) from 7440-itemComparativeOptimization into dev
gitea/salix/pipeline/head This commit looks good Details

Reviewed-on: #2501
Reviewed-by: Javi Gallego <jgallego@verdnatura.es>
This commit is contained in:
Guillermo Bonet 2024-05-23 08:55:57 +00:00
commit 1730276844
1 changed files with 58 additions and 59 deletions

View File

@ -6,7 +6,7 @@ CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`item_comparative`(
vAvailableSince DATE, vAvailableSince DATE,
vBuyerFk INT, vBuyerFk INT,
vIsFloramondo BOOL, vIsFloramondo BOOL,
vCountryFk INT vCountryFk INT
) )
proc: BEGIN proc: BEGIN
/** /**
@ -23,7 +23,6 @@ proc: BEGIN
* @param tmp.comparativeFilterType(filterFk INT ,itemTypeFk INT) * @param tmp.comparativeFilterType(filterFk INT ,itemTypeFk INT)
* @return tmp.comparative * @return tmp.comparative
*/ */
DECLARE vDayRangeStart DATE; DECLARE vDayRangeStart DATE;
DECLARE vDayRangeEnd DATE; DECLARE vDayRangeEnd DATE;
DECLARE w1, w2, w3, w4, w5, w6, w7 INT; DECLARE w1, w2, w3, w4, w5, w6, w7 INT;
@ -59,14 +58,14 @@ proc: BEGIN
END IF; END IF;
SELECT MIN(dated) INTO vDayRangeStart SELECT MIN(dated) INTO vDayRangeStart
FROM vn.time FROM `time`
WHERE dated <= vDate WHERE dated <= vDate
GROUP BY period GROUP BY period
ORDER BY dated desc ORDER BY dated desc
LIMIT 1 OFFSET vWeekRange; LIMIT 1 OFFSET vWeekRange;
SELECT MAX(dated) INTO vDayRangeEnd SELECT MAX(dated) INTO vDayRangeEnd
FROM vn.time FROM `time`
WHERE dated >= vDate WHERE dated >= vDate
GROUP BY period GROUP BY period
ORDER BY dated ASC ORDER BY dated ASC
@ -83,12 +82,11 @@ proc: BEGIN
JOIN itemType t ON t.id = i.typeFk JOIN itemType t ON t.id = i.typeFk
JOIN itemCategory c ON c.id = t.categoryFk JOIN itemCategory c ON c.id = t.categoryFk
LEFT JOIN worker w ON w.id = t.workerFk LEFT JOIN worker w ON w.id = t.workerFk
WHERE (NOT vHasTypeFilter WHERE (NOT vHasTypeFilter OR t.id IN (
OR t.id IN (SELECT itemTypeFk FROM tmp.comparativeFilterType)) SELECT itemTypeFk FROM tmp.comparativeFilterType
AND (vBuyerFk IS NULL ))
OR t.workerFk = vBuyerFk) AND (vBuyerFk IS NULL OR t.workerFk = vBuyerFk)
AND (vIsFloramondo IS NULL AND (vIsFloramondo IS NULL OR i.isFloramondo = vIsFloramondo);
OR i.isFloramondo = vIsFloramondo);
IF vDate < util.VN_CURDATE() THEN IF vDate < util.VN_CURDATE() THEN
ALTER TABLE tmp.itemInventory ALTER TABLE tmp.itemInventory
@ -115,10 +113,11 @@ proc: BEGIN
SET i = i + 1; SET i = i + 1;
SELECT t.period INTO vPeriod SELECT t.period INTO vPeriod
FROM vn.`time` t FROM `time` t
WHERE t.dated = vDayRangeStart + INTERVAL (vWeekCount * (i - 1)) DAY; WHERE t.dated = vDayRangeStart + INTERVAL (vWeekCount * (i - 1)) DAY;
INSERT IGNORE INTO tTable(cy, ly, zy) VALUES(vPeriod, vPeriod - 100, vPeriod - 200); INSERT IGNORE INTO tTable(cy, ly, zy)
VALUES(vPeriod, vPeriod - 100, vPeriod - 200);
UNTIL i = vWeekCount END REPEAT; UNTIL i = vWeekCount END REPEAT;
SELECT cy, ly, zy INTO w1, y1, z1 FROM tTable LIMIT 1; SELECT cy, ly, zy INTO w1, y1, z1 FROM tTable LIMIT 1;
@ -130,7 +129,6 @@ proc: BEGIN
SELECT cy, ly, zy INTO w7, y7, z7 FROM tTable WHERE cy > w6 LIMIT 1; SELECT cy, ly, zy INTO w7, y7, z7 FROM tTable WHERE cy > w6 LIMIT 1;
-- Genera una tabla con los datos del año pasado. -- Genera una tabla con los datos del año pasado.
CREATE OR REPLACE TEMPORARY TABLE tLastYear CREATE OR REPLACE TEMPORARY TABLE tLastYear
(KEY (lItemFk)) (KEY (lItemFk))
ENGINE = MEMORY ENGINE = MEMORY
@ -151,15 +149,14 @@ proc: BEGIN
SUM(IF(c.timePeriod = y7, c.price, 0)) lprice7 SUM(IF(c.timePeriod = y7, c.price, 0)) lprice7
FROM tmp.itemInventory ai FROM tmp.itemInventory ai
JOIN comparative c ON c.itemFk = ai.id JOIN comparative c ON c.itemFk = ai.id
JOIN warehouse w on w.id = c.warehouseFk JOIN warehouse w ON w.id = c.warehouseFk
JOIN tTable wt ON c.timePeriod = wt.ly JOIN tTable wt ON c.timePeriod = wt.ly
WHERE IFNULL(vWarehouseFk, c.warehouseFk) = c.warehouseFk WHERE (vWarehouseFk IS NULL OR vWarehouseFk = c.warehouseFk)
AND w.isComparative AND w.isComparative
AND (vCountryFk IS NULL OR c.countryFk = vCountryFk) AND (vCountryFk IS NULL OR c.countryFk = vCountryFk)
GROUP BY ai.id; GROUP BY ai.id;
-- Genera una tabla con los datos de hace DOS años. -- Genera una tabla con los datos de hace 2 años
CREATE OR REPLACE TEMPORARY TABLE tTwoYearsAgo CREATE OR REPLACE TEMPORARY TABLE tTwoYearsAgo
(KEY (tItemFk)) (KEY (tItemFk))
ENGINE = MEMORY ENGINE = MEMORY
@ -180,73 +177,72 @@ proc: BEGIN
SUM(IF(c.timePeriod = z7, c.price, 0)) vlprice7 SUM(IF(c.timePeriod = z7, c.price, 0)) vlprice7
FROM tmp.itemInventory ai FROM tmp.itemInventory ai
JOIN comparative c ON c.itemFk = ai.id JOIN comparative c ON c.itemFk = ai.id
JOIN warehouse w on w.id = c.warehouseFk JOIN warehouse w ON w.id = c.warehouseFk
JOIN tTable wt ON c.timePeriod = wt.zy JOIN tTable wt ON c.timePeriod = wt.zy
WHERE IFNULL(vWarehouseFk, c.warehouseFk) = c.warehouseFk WHERE (vWarehouseFk IS NULL OR vWarehouseFk = c.warehouseFk)
AND w.isComparative AND w.isComparative
AND (vCountryFk IS NULL OR c.countryFk = vCountryFk) AND (vCountryFk IS NULL OR c.countryFk = vCountryFk)
GROUP BY ai.id; GROUP BY ai.id;
-- Genera una tabla con los datos de este año.ss -- Genera una tabla con los datos de este año
CREATE OR REPLACE TEMPORARY TABLE tCurrentYear CREATE OR REPLACE TEMPORARY TABLE tCurrentYear
(KEY (cItemFk)) (KEY (cItemFk))
ENGINE = MEMORY ENGINE = MEMORY
SELECT t.itemFk cItemFk, SELECT t.itemFk cItemFk,
SUM(IF(week = w1, total, 0)) cweek1, SUM(IF(`week` = w1, total, 0)) cweek1,
SUM(IF(week = w2, total, 0)) cweek2, SUM(IF(`week` = w2, total, 0)) cweek2,
SUM(IF(week = w3, total, 0)) cweek3, SUM(IF(`week` = w3, total, 0)) cweek3,
SUM(IF(week = w4, total, 0)) cweek4, SUM(IF(`week` = w4, total, 0)) cweek4,
SUM(IF(week = w5, total, 0)) cweek5, SUM(IF(`week` = w5, total, 0)) cweek5,
SUM(IF(week = w6, total, 0)) cweek6, SUM(IF(`week` = w6, total, 0)) cweek6,
SUM(IF(week = w7, total, 0)) cweek7, SUM(IF(`week` = w7, total, 0)) cweek7,
SUM(IF(week = w1, price, 0)) cprice1, SUM(IF(`week` = w1, price, 0)) cprice1,
SUM(IF(week = w2, price, 0)) cprice2, SUM(IF(`week` = w2, price, 0)) cprice2,
SUM(IF(week = w3, price, 0)) cprice3, SUM(IF(`week` = w3, price, 0)) cprice3,
SUM(IF(week = w4, price, 0)) cprice4, SUM(IF(`week` = w4, price, 0)) cprice4,
SUM(IF(week = w5, price, 0)) cprice5, SUM(IF(`week` = w5, price, 0)) cprice5,
SUM(IF(week = w6, price, 0)) cprice6, SUM(IF(`week` = w6, price, 0)) cprice6,
SUM(IF(week = w7, price, 0)) cprice7 SUM(IF(`week` = w7, price, 0)) cprice7
FROM ( FROM (
SELECT s.itemFk, SELECT s.itemFk,
ti.period `week`, ti.period `week`,
SUM(s.quantity) total, SUM(s.quantity) total,
TRUNCATE(SUM(s.quantity * s.priceFixed),0) price TRUNCATE(SUM(s.quantity * s.priceFixed), 0) price
FROM ticket t FROM ticket t FORCE INDEX (Fecha)
JOIN sale s ON t.id = s.ticketFk JOIN sale s ON t.id = s.ticketFk
JOIN tmp.itemInventory it ON it.id = s.itemFk JOIN tmp.itemInventory it ON it.id = s.itemFk
JOIN time ti ON ti.dated = DATE(t.shipped) JOIN `time` ti ON ti.dated = DATE(t.shipped)
JOIN item i ON i.id = s.itemFk JOIN item i ON i.id = s.itemFk
JOIN itemType tp ON tp.id = i.typeFk JOIN itemType tp ON tp.id = i.typeFk
JOIN itemCategory ic ON ic.id = tp.categoryFk JOIN itemCategory ic ON ic.id = tp.categoryFk
JOIN warehouse w ON w.id = t.warehouseFk JOIN warehouse w ON w.id = t.warehouseFk
STRAIGHT_JOIN address ad ON ad.id = t.addressFk JOIN `address` ad ON ad.id = t.addressFk
JOIN province p ON p.id = ad.provinceFk JOIN province p ON p.id = ad.provinceFk
JOIN `client` c ON c.id = ad.clientFk JOIN `client` c ON c.id = ad.clientFk
WHERE t.shipped BETWEEN vDayRangeStart AND util.dayEnd(vDayRangeEnd) WHERE t.shipped BETWEEN vDayRangeStart AND util.dayEnd(vDayRangeEnd)
AND c.typeFk IN ('Normal','handMaking') AND c.typeFk IN ('normal', 'handMaking')
AND w.id = COALESCE(vWarehouseFk, w.id) AND (vWarehouseFk IS NULL OR vWarehouseFk = w.id)
AND (vCountryFk IS NULL OR p.countryFk = vCountryFk)
AND w.isComparative AND w.isComparative
AND (vCountryFk IS NULL OR p.countryFk = vCountryFk) GROUP BY i.id, `week`
GROUP BY i.id, week
) t ) t
GROUP BY t.itemFk; GROUP BY t.itemFk;
-- Genera la tabla con la comparativa. -- Genera la tabla con la comparativa
CREATE OR REPLACE TEMPORARY TABLE tmp.comparative CREATE OR REPLACE TEMPORARY TABLE tmp.comparative
ENGINE = MEMORY ENGINE = MEMORY
SELECT it.subName productor, SELECT it.subName productor,
b.packing, b.packing,
b.buyingValue costefijo, b.buyingValue costefijo,
b.groupingMode caja, b.groupingMode caja,
it.image ArticleImage, it.image ArticleImage,
IFNULL(it.inkFk,"?") color, IFNULL(it.inkFk, '?') color,
tp.code tipo, tp.code tipo,
it.typeFk tipo_id, it.typeFk tipo_id,
o.code origen, o.code origen,
it.category categoria, it.category categoria,
it.stems tallos, it.stems tallos,
it.size medida, it.`size` medida,
it.name article, it.name article,
w.code codigoTrabajador, w.code codigoTrabajador,
tp.categoryFk reino_id, tp.categoryFk reino_id,
@ -257,24 +253,27 @@ proc: BEGIN
it.id Id_Article, it.id Id_Article,
i.buy_id, i.buy_id,
tp.life, tp.life,
IFNULL(i.sd,0) sd, IFNULL(i.sd, 0) sd,
i.avalaible, i.avalaible,
i.visible, i.visible,
i.buy_date, i.buy_date,
e.id provider_id, e.id provider_id,
it.comment comments, it.comment comments,
it.description itemDescription, it.description itemDescription,
IF(cy.cItemFk IS NULL AND i.visible = 0 AND i.avalaible = 0 IF(cy.cItemFk IS NULL AND i.visible = 0
AND IFNULL(i.sd, 0) = 0, FALSE, TRUE) filtret, AND i.avalaible = 0 AND (i.sd IS NULL OR i.sd = 0),
FALSE,
TRUE
) filtret,
IF(it.hasMinPrice, FORMAT(it.minPrice, 2), "") pvp, IF(it.hasMinPrice, FORMAT(it.minPrice, 2), "") pvp,
s.company_name s.company_name
FROM tmp.itemInventory i FROM tmp.itemInventory i
JOIN item it ON it.id = i.id JOIN item it ON it.id = i.id
LEFT JOIN itemType tp ON tp.id = it.typeFk JOIN itemType tp ON tp.id = it.typeFk
LEFT JOIN worker w ON w.id = tp.workerFk JOIN worker w ON w.id = tp.workerFk
LEFT JOIN buy b ON b.id = i.buy_id LEFT JOIN buy b ON b.id = i.buy_id
LEFT JOIN entry e ON e.id = b.entryFk LEFT JOIN `entry` e ON e.id = b.entryFk
LEFT JOIN origin o ON o.id = it.originFk JOIN origin o ON o.id = it.originFk
LEFT JOIN tLastYear ly ON ly.lItemFk = it.id LEFT JOIN tLastYear ly ON ly.lItemFk = it.id
LEFT JOIN tCurrentYear cy ON cy.cItemFk = it.id LEFT JOIN tCurrentYear cy ON cy.cItemFk = it.id
LEFT JOIN tTwoYearsAgo zy ON zy.tItemFk = it.id LEFT JOIN tTwoYearsAgo zy ON zy.tItemFk = it.id
@ -287,8 +286,8 @@ proc: BEGIN
OR ly.lweek1 OR ly.lweek2 OR ly.lweek3 OR ly.lweek4 OR ly.lweek5 OR ly.lweek6 OR ly.lweek7 OR ly.lweek1 OR ly.lweek2 OR ly.lweek3 OR ly.lweek4 OR ly.lweek5 OR ly.lweek6 OR ly.lweek7
OR zy.vlweek1 OR zy.vlweek2 OR zy.vlweek3 OR zy.vlweek4 OR zy.vlweek5 OR zy.vlweek6 OR zy.vlweek7; OR zy.vlweek1 OR zy.vlweek2 OR zy.vlweek3 OR zy.vlweek4 OR zy.vlweek5 OR zy.vlweek6 OR zy.vlweek7;
-- Elimina las tablas temporales creadas... DROP TEMPORARY TABLE IF EXISTS
DROP TEMPORARY TABLE IF EXISTS tmp.itemInventory, tmp.itemInventory,
tTwoYearsAgo, tTwoYearsAgo,
tLastYear, tLastYear,
tCurrentYear, tCurrentYear,