refs #7440 Optimized item_comparative
This commit is contained in:
parent
4c5f46eb9b
commit
56aec1c781
|
@ -6,23 +6,23 @@ CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`item_comparative`(
|
|||
vAvailableSince DATE,
|
||||
vBuyerFk INT,
|
||||
vIsFloramondo BOOL,
|
||||
vCountryFk INT
|
||||
vCountryFk INT
|
||||
)
|
||||
proc: BEGIN
|
||||
/**
|
||||
* Genera una tabla de comparativa de artículos por itemType/comprador/fecha.
|
||||
* Los datos se calculan en función de los parámetros proporcionados.
|
||||
*
|
||||
* @param vDate La fecha para la cual se generará la comparativa.
|
||||
* @param vDayRange El rango de días a considerar para la comparativa.
|
||||
* @param vWarehouseFk El identificador del almacén para filtrar los artículos.
|
||||
* @param vAvailableSince La fecha de disponibilidad desde la cual se consideran los artículos disponibles.
|
||||
* @param vBuyerFk El identificador del comprador para filtrar los artículos.
|
||||
* @param vIsFloramondo Indica si se deben incluir solo los artículos de Floramondo (opcional).
|
||||
* @param vCountryFk El identificador del país.
|
||||
* @param tmp.comparativeFilterType(filterFk INT ,itemTypeFk INT)
|
||||
* @return tmp.comparative
|
||||
*/
|
||||
* Genera una tabla de comparativa de artículos por itemType/comprador/fecha.
|
||||
* Los datos se calculan en función de los parámetros proporcionados.
|
||||
*
|
||||
* @param vDate La fecha para la cual se generará la comparativa.
|
||||
* @param vDayRange El rango de días a considerar para la comparativa.
|
||||
* @param vWarehouseFk El identificador del almacén para filtrar los artículos.
|
||||
* @param vAvailableSince La fecha de disponibilidad desde la cual se consideran los artículos disponibles.
|
||||
* @param vBuyerFk El identificador del comprador para filtrar los artículos.
|
||||
* @param vIsFloramondo Indica si se deben incluir solo los artículos de Floramondo (opcional).
|
||||
* @param vCountryFk El identificador del país.
|
||||
* @param tmp.comparativeFilterType(filterFk INT ,itemTypeFk INT)
|
||||
* @return tmp.comparative
|
||||
*/
|
||||
|
||||
DECLARE vDayRangeStart DATE;
|
||||
DECLARE vDayRangeEnd DATE;
|
||||
|
@ -59,14 +59,14 @@ proc: BEGIN
|
|||
END IF;
|
||||
|
||||
SELECT MIN(dated) INTO vDayRangeStart
|
||||
FROM vn.time
|
||||
FROM `time`
|
||||
WHERE dated <= vDate
|
||||
GROUP BY period
|
||||
ORDER BY dated desc
|
||||
LIMIT 1 OFFSET vWeekRange;
|
||||
|
||||
SELECT MAX(dated) INTO vDayRangeEnd
|
||||
FROM vn.time
|
||||
FROM `time`
|
||||
WHERE dated >= vDate
|
||||
GROUP BY period
|
||||
ORDER BY dated ASC
|
||||
|
@ -83,12 +83,11 @@ proc: BEGIN
|
|||
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);
|
||||
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
|
||||
|
@ -115,10 +114,11 @@ proc: BEGIN
|
|||
SET i = i + 1;
|
||||
|
||||
SELECT t.period INTO vPeriod
|
||||
FROM vn.`time` t
|
||||
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);
|
||||
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;
|
||||
|
@ -130,7 +130,6 @@ proc: BEGIN
|
|||
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
|
||||
|
@ -153,13 +152,12 @@ proc: BEGIN
|
|||
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 IFNULL(vWarehouseFk, c.warehouseFk) = c.warehouseFk
|
||||
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 DOS años.
|
||||
|
||||
CREATE OR REPLACE TEMPORARY TABLE tTwoYearsAgo
|
||||
(KEY (tItemFk))
|
||||
ENGINE = MEMORY
|
||||
|
@ -182,71 +180,70 @@ proc: BEGIN
|
|||
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 IFNULL(vWarehouseFk, c.warehouseFk) = c.warehouseFk
|
||||
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.ss
|
||||
|
||||
-- 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
|
||||
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
|
||||
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 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
|
||||
STRAIGHT_JOIN address ad ON ad.id = t.addressFk
|
||||
JOIN province p ON p.id = ad.provinceFk
|
||||
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 w.id = COALESCE(vWarehouseFk, w.id)
|
||||
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
|
||||
AND (vCountryFk IS NULL OR p.countryFk = vCountryFk)
|
||||
GROUP BY i.id, week
|
||||
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,
|
||||
SELECT it.subName productor,
|
||||
b.packing,
|
||||
b.buyingValue costefijo,
|
||||
b.groupingMode caja,
|
||||
it.image ArticleImage,
|
||||
IFNULL(it.inkFk,"?") color,
|
||||
IFNULL(it.inkFk, '?') color,
|
||||
tp.code tipo,
|
||||
it.typeFk tipo_id,
|
||||
o.code origen,
|
||||
it.category categoria,
|
||||
it.stems tallos,
|
||||
it.size medida,
|
||||
it.`size` medida,
|
||||
it.name article,
|
||||
w.code codigoTrabajador,
|
||||
tp.categoryFk reino_id,
|
||||
|
@ -257,24 +254,27 @@ proc: BEGIN
|
|||
it.id Id_Article,
|
||||
i.buy_id,
|
||||
tp.life,
|
||||
IFNULL(i.sd,0) sd,
|
||||
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 IFNULL(i.sd, 0) = 0, FALSE, TRUE) filtret,
|
||||
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
|
||||
LEFT JOIN itemType tp ON tp.id = it.typeFk
|
||||
LEFT JOIN worker w ON w.id = tp.workerFk
|
||||
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
|
||||
LEFT JOIN origin o ON o.id = it.originFk
|
||||
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
|
||||
|
@ -287,8 +287,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 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 tmp.itemInventory,
|
||||
DROP TEMPORARY TABLE IF EXISTS
|
||||
tmp.itemInventory,
|
||||
tTwoYearsAgo,
|
||||
tLastYear,
|
||||
tCurrentYear,
|
||||
|
|
Loading…
Reference in New Issue