DELIMITER $$ CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`item_comparative`( vDate DATETIME, vDayRange TINYINT, vWarehouseFk TINYINT, vAvailableSince DATE, vBuyerFk INT, vIsFloramondo BOOL, vCountryFk INT ) proc: BEGIN /** * Generates a comparison table of items by itemType/buyer/date. * The data is calculated based on the provided parameters. * * @param vDate The date for which the comparison will be generated. * @param vDayRange The range of days to consider for the comparison. * @param vWarehouseFk The warehouse identifier to filter the items. * @param vAvailableSince The availability date from which the items are considered available. * @param vBuyerFk The buyer identifier to filter the items. * @param vIsFloramondo Indicates whether only Floramondo items should be included (optional). * @param vCountryFk The country identifier. * @param tmp.comparativeFilterType(filterFk INT, itemTypeFk INT) * @return tmp.comparative */ DECLARE vDayRangeStart DATE; DECLARE vDayRangeEnd DATE; DECLARE w1, w2, w3, w4, w5, w6, w7 INT; DECLARE y1, y2, y3, y4, y5, y6, y7 INT; DECLARE z1, z2, z3, z4, z5, z6, z7 INT; DECLARE vPeriod INT; DECLARE i INT DEFAULT 0; DECLARE vHasTypeFilter BOOL; DECLARE vWeekRange INT; DECLARE vWeekCount TINYINT; DECLARE vMaxDayRange INT; DECLARE vMinDayRange INT; DECLARE vDefaultDayRange INT; IF NOT(SELECT COUNT(*) FROM comparativeConfig)THEN LEAVE proc; END IF; SELECT weekRange, weekRange * 2 + 1, maxDayRange, minDayRange, defaultDayRange INTO vWeekRange, vWeekCount, vMaxDayRange, vMinDayRange, vDefaultDayRange FROM comparativeConfig; IF vDayRange < vMinDayRange OR vDayRange > vMaxDayRange THEN SET vDayRange = vDefaultDayRange; END IF; SELECT MIN(dated) INTO vDayRangeStart FROM `time` WHERE dated <= vDate GROUP BY period ORDER BY dated desc LIMIT 1 OFFSET vWeekRange; SELECT MAX(dated) INTO vDayRangeEnd FROM `time` WHERE dated >= vDate GROUP BY period ORDER BY dated ASC LIMIT 1 OFFSET vWeekRange; SELECT COUNT(itemTypeFk) > 0 INTO vHasTypeFilter FROM tmp.comparativeFilterType; CREATE OR REPLACE TEMPORARY TABLE tmp.itemInventory (PRIMARY KEY (id)) ENGINE = MEMORY SELECT i.id FROM item i JOIN itemType t ON t.id = i.typeFk JOIN itemCategory c ON c.id = t.categoryFk LEFT JOIN worker w ON w.id = t.workerFk WHERE (NOT vHasTypeFilter OR t.id IN ( SELECT itemTypeFk FROM tmp.comparativeFilterType )) AND (vBuyerFk IS NULL OR t.workerFk = vBuyerFk) AND (vIsFloramondo IS NULL OR i.isFloramondo = vIsFloramondo); IF vDate < util.VN_CURDATE() THEN ALTER TABLE tmp.itemInventory ADD `buy_id` INT NOT NULL DEFAULT 0, ADD `buy_date` DATE DEFAULT '2000-01-01', ADD `life` INT DEFAULT 0, ADD `sd` INT DEFAULT 0, ADD `avalaible` INT DEFAULT 0, ADD `visible` INT DEFAULT 0; ELSE CALL multipleInventory(vAvailableSince, vWarehouseFk, vDayRange); CALL item_multipleBuy(vDate, vWarehouseFk); CALL item_multipleBuyByDate(vDate, vWarehouseFk); END IF; CREATE OR REPLACE TEMPORARY TABLE tTable ( cy INT(6) PRIMARY KEY, ly INT(6), zy INT(6), INDEX (ly) ); REPEAT SET i = i + 1; SELECT t.period INTO vPeriod FROM `time` t WHERE t.dated = vDayRangeStart + INTERVAL (vWeekCount * (i - 1)) DAY; INSERT IGNORE INTO tTable(cy, ly, zy) VALUES(vPeriod, vPeriod - 100, vPeriod - 200); UNTIL i = vWeekCount END REPEAT; SELECT cy, ly, zy INTO w1, y1, z1 FROM tTable LIMIT 1; SELECT cy, ly, zy INTO w2, y2, z2 FROM tTable WHERE cy > w1 LIMIT 1; SELECT cy, ly, zy INTO w3, y3, z3 FROM tTable WHERE cy > w2 LIMIT 1; SELECT cy, ly, zy INTO w4, y4, z4 FROM tTable WHERE cy > w3 LIMIT 1; SELECT cy, ly, zy INTO w5, y5, z5 FROM tTable WHERE cy > w4 LIMIT 1; SELECT cy, ly, zy INTO w6, y6, z6 FROM tTable WHERE cy > w5 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. CREATE OR REPLACE TEMPORARY TABLE tLastYear (KEY (lItemFk)) ENGINE = MEMORY SELECT c.itemFk lItemFk, SUM(IF(c.timePeriod = y1, c.quantity, 0)) lweek1, SUM(IF(c.timePeriod = y2, c.quantity, 0)) lweek2, SUM(IF(c.timePeriod = y3, c.quantity, 0)) lweek3, SUM(IF(c.timePeriod = y4, c.quantity, 0)) lweek4, SUM(IF(c.timePeriod = y5, c.quantity, 0)) lweek5, SUM(IF(c.timePeriod = y6, c.quantity, 0)) lweek6, SUM(IF(c.timePeriod = y7, c.quantity, 0)) lweek7, SUM(IF(c.timePeriod = y1, c.price, 0)) lprice1, SUM(IF(c.timePeriod = y2, c.price, 0)) lprice2, SUM(IF(c.timePeriod = y3, c.price, 0)) lprice3, SUM(IF(c.timePeriod = y4, c.price, 0)) lprice4, SUM(IF(c.timePeriod = y5, c.price, 0)) lprice5, SUM(IF(c.timePeriod = y6, c.price, 0)) lprice6, SUM(IF(c.timePeriod = y7, c.price, 0)) lprice7 FROM tmp.itemInventory ai JOIN comparative c ON c.itemFk = ai.id JOIN warehouse w ON w.id = c.warehouseFk JOIN tTable wt ON c.timePeriod = wt.ly WHERE (vWarehouseFk IS NULL OR vWarehouseFk = c.warehouseFk) AND w.isComparative AND (vCountryFk IS NULL OR c.countryFk = vCountryFk) GROUP BY ai.id; -- Genera una tabla con los datos de hace 2 años CREATE OR REPLACE TEMPORARY TABLE tTwoYearsAgo (KEY (tItemFk)) ENGINE = MEMORY SELECT c.itemFk tItemFk, SUM(IF(c.timePeriod = z1, c.quantity, 0)) vlweek1, SUM(IF(c.timePeriod = z2, c.quantity, 0)) vlweek2, SUM(IF(c.timePeriod = z3, c.quantity, 0)) vlweek3, SUM(IF(c.timePeriod = z4, c.quantity, 0)) vlweek4, SUM(IF(c.timePeriod = z5, c.quantity, 0)) vlweek5, SUM(IF(c.timePeriod = z6, c.quantity, 0)) vlweek6, SUM(IF(c.timePeriod = z7, c.quantity, 0)) vlweek7, SUM(IF(c.timePeriod = z1, c.price, 0)) vlprice1, SUM(IF(c.timePeriod = z2, c.price, 0)) vlprice2, SUM(IF(c.timePeriod = z3, c.price, 0)) vlprice3, SUM(IF(c.timePeriod = z4, c.price, 0)) vlprice4, SUM(IF(c.timePeriod = z5, c.price, 0)) vlprice5, SUM(IF(c.timePeriod = z6, c.price, 0)) vlprice6, SUM(IF(c.timePeriod = z7, c.price, 0)) vlprice7 FROM tmp.itemInventory ai JOIN comparative c ON c.itemFk = ai.id JOIN warehouse w ON w.id = c.warehouseFk JOIN tTable wt ON c.timePeriod = wt.zy WHERE (vWarehouseFk IS NULL OR vWarehouseFk = c.warehouseFk) AND w.isComparative AND (vCountryFk IS NULL OR c.countryFk = vCountryFk) GROUP BY ai.id; -- Genera una tabla con los datos de este año CREATE OR REPLACE TEMPORARY TABLE tCurrentYear (KEY (cItemFk)) ENGINE = MEMORY SELECT t.itemFk cItemFk, SUM(IF(`week` = w1, total, 0)) cweek1, SUM(IF(`week` = w2, total, 0)) cweek2, SUM(IF(`week` = w3, total, 0)) cweek3, SUM(IF(`week` = w4, total, 0)) cweek4, SUM(IF(`week` = w5, total, 0)) cweek5, SUM(IF(`week` = w6, total, 0)) cweek6, SUM(IF(`week` = w7, total, 0)) cweek7, SUM(IF(`week` = w1, price, 0)) cprice1, SUM(IF(`week` = w2, price, 0)) cprice2, SUM(IF(`week` = w3, price, 0)) cprice3, SUM(IF(`week` = w4, price, 0)) cprice4, SUM(IF(`week` = w5, price, 0)) cprice5, SUM(IF(`week` = w6, price, 0)) cprice6, SUM(IF(`week` = w7, price, 0)) cprice7 FROM ( SELECT s.itemFk, ti.period `week`, SUM(s.quantity) total, TRUNCATE(SUM(s.quantity * s.priceFixed), 0) price FROM ticket t FORCE INDEX (Fecha) JOIN sale s ON t.id = s.ticketFk JOIN tmp.itemInventory it ON it.id = s.itemFk JOIN `time` ti ON ti.dated = DATE(t.shipped) JOIN item i ON i.id = s.itemFk JOIN itemType tp ON tp.id = i.typeFk JOIN itemCategory ic ON ic.id = tp.categoryFk JOIN warehouse w ON w.id = t.warehouseFk JOIN `address` ad ON ad.id = t.addressFk JOIN province p ON p.id = ad.provinceFk JOIN `client` c ON c.id = ad.clientFk WHERE t.shipped BETWEEN vDayRangeStart AND util.dayEnd(vDayRangeEnd) AND c.typeFk IN ('normal', 'handMaking') AND (vWarehouseFk IS NULL OR vWarehouseFk = w.id) AND (vCountryFk IS NULL OR p.countryFk = vCountryFk) AND w.isComparative GROUP BY i.id, `week` ) t GROUP BY t.itemFk; -- Genera la tabla con la comparativa CREATE OR REPLACE TEMPORARY TABLE tmp.comparative ENGINE = MEMORY SELECT it.subName productor, b.packing, b.buyingValue costefijo, b.groupingMode caja, it.image ArticleImage, IFNULL(it.inkFk, '?') color, tp.code tipo, it.typeFk tipo_id, o.code origen, it.category categoria, it.stems tallos, it.`size` medida, it.name article, w.code codigoTrabajador, tp.categoryFk reino_id, ly.*, cy.*, zy.*, it.*, it.id Id_Article, i.buy_id, tp.life, IFNULL(i.sd, 0) sd, i.avalaible, i.visible, i.buy_date, e.id provider_id, it.comment comments, it.description itemDescription, IF(cy.cItemFk IS NULL AND i.visible = 0 AND i.avalaible = 0 AND (i.sd IS NULL OR i.sd = 0), FALSE, TRUE ) filtret, IF(it.hasMinPrice, FORMAT(it.minPrice, 2), "") pvp, s.company_name FROM tmp.itemInventory i JOIN item it ON it.id = i.id JOIN itemType tp ON tp.id = it.typeFk JOIN worker w ON w.id = tp.workerFk LEFT JOIN buy b ON b.id = i.buy_id LEFT JOIN `entry` e ON e.id = b.entryFk JOIN origin o ON o.id = it.originFk LEFT JOIN tLastYear ly ON ly.lItemFk = it.id LEFT JOIN tCurrentYear cy ON cy.cItemFk = it.id LEFT JOIN tTwoYearsAgo zy ON zy.tItemFk = it.id LEFT JOIN edi.ekt e2 ON e2.id = b.ektFk LEFT JOIN edi.supplier s ON s.supplier_id = e2.pro WHERE i.avalaible OR i.visible OR i.sd OR cy.cweek1 OR cy.cweek2 OR cy.cweek3 OR cy.cweek4 OR cy.cweek5 OR cy.cweek6 OR cy.cweek7 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; DROP TEMPORARY TABLE IF EXISTS tmp.itemInventory, tTwoYearsAgo, tLastYear, tCurrentYear, tTable; END$$ DELIMITER ;