salix/db/routines/vn/procedures/catalog_calculate.sql

220 lines
7.0 KiB
MySQL
Raw Normal View History

DELIMITER $$
2024-08-20 08:06:10 +00:00
CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`catalog_calculate`(
2024-03-25 13:56:12 +00:00
vLanded DATE,
vAddressFk INT,
vAgencyModeFk INT,
2024-11-27 17:19:57 +00:00
vCurrencyFk INT,
vShowExpiredZones BOOLEAN
)
BEGIN
/**
2024-11-27 17:19:57 +00:00
* Calcula los articulos disponibles y sus precios.
*
* @table tmp.item(itemFk) Listado de artículos a calcular
* @param vLanded Fecha de recepcion de mercancia
* @param vAddressFk Id del consignatario
* @param vAgencyModeFk Id de la agencia
2024-11-27 17:19:57 +00:00
* @param vCurrencyFk Id de la moneda
* @return tmp.ticketCalculateItem(itemFk, available, producer, item, size, stems,
* category, inkFk,image, origin, price, priceKg, foreignPrice,
* foreignPriceKg, grouping, minQuantity)
* @return tmp.ticketLot(warehouseFk, itemFk, available, buyFk)
* @return tmp.ticketComponent
* @return tmp.ticketComponentPrice
*/
DECLARE vAvailableCalc INT;
DECLARE vAvailableNoRaidsCalc INT;
DECLARE vShipped DATE;
DECLARE vWarehouseFk SMALLINT;
DECLARE vZoneFk INT;
DECLARE vDone BOOL;
DECLARE cTravelTree CURSOR FOR
SELECT zoneFk, warehouseFk, shipped FROM tmp.zoneGetShipped;
DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE;
2024-07-22 11:34:04 +00:00
CALL zone_getShipped (vLanded, vAddressFk, vAgencyModeFk, vShowExpiredZones);
DROP TEMPORARY TABLE IF EXISTS tmp.ticketLot;
CREATE TEMPORARY TABLE tmp.ticketLot(
`warehouseFk` smallint(5) unsigned NOT NULL,
`itemFk` int(11) NOT NULL,
`available` double DEFAULT NULL,
`buyFk` int(11) DEFAULT NULL,
`fix` tinyint(3) unsigned DEFAULT '0', -- este campo parece obsoleto
`zoneFk` int(11) NOT NULL,
KEY `itemFk` (`itemFk`),
KEY `item_warehouse` (`itemFk`,`warehouseFk`) USING HASH
) ENGINE=MEMORY DEFAULT CHARSET=utf8;
CALL catalog_componentPrepare();
2024-07-11 11:32:34 +00:00
CREATE OR REPLACE TEMPORARY TABLE tmp.ticketCalculateItem(
2024-11-27 17:19:57 +00:00
itemFk INT(11) NOT NULL,
available INT(11),
2024-11-27 17:19:57 +00:00
producer VARCHAR(50),
item VARCHAR(50),
size INT(10) UNSIGNED,
stems INT(11),
category VARCHAR(3),
inkFk VARCHAR(3),
image VARCHAR(50),
2024-11-27 17:19:57 +00:00
origin VARCHAR(3),
price DECIMAL(10,2),
priceKg DECIMAL(10,2),
2024-11-27 17:19:57 +00:00
foreignPrice DECIMAL(10,2),
foreignPriceKg DECIMAL(10,2),
`grouping` INT(10) UNSIGNED,
2024-07-12 05:58:59 +00:00
minQuantity INT(10) UNSIGNED,
PRIMARY KEY `itemFk` (`itemFk`)
) ENGINE = MEMORY DEFAULT CHARSET=utf8;
2024-11-27 17:19:57 +00:00
OPEN cTravelTree;
l: LOOP
SET vDone = FALSE;
FETCH cTravelTree INTO vZoneFk, vWarehouseFk, vShipped;
IF vDone THEN
LEAVE l;
END IF;
2024-07-22 11:39:48 +00:00
CALL `cache`.available_refresh(vAvailableCalc, FALSE, vWarehouseFk, vShipped);
CALL `cache`.availableNoRaids_refresh(vAvailableNoRaidsCalc, FALSE, vWarehouseFk, vShipped);
2024-07-22 09:58:51 +00:00
CALL buy_getUltimate(NULL, vWarehouseFk, vShipped);
INSERT INTO tmp.ticketLot (warehouseFk, itemFk, available, buyFk, zoneFk)
SELECT vWarehouseFk,
a.item_id,
IFNULL(a.available, 0),
bu.buyFk,
vZoneFk
FROM `cache`.available a
2024-11-27 17:19:57 +00:00
LEFT JOIN cache.availableNoRaids anr ON anr.item_id = a.item_id
AND anr.calc_id = vAvailableNoRaidsCalc
JOIN tmp.item i ON i.itemFk = a.item_id
2024-07-22 11:34:04 +00:00
JOIN item it ON it.id = i.itemFk
JOIN `zone` z ON z.id = vZoneFk
2024-11-27 17:19:57 +00:00
LEFT JOIN tmp.buyUltimate bu ON bu.itemFk = a.item_id
LEFT JOIN edi.supplyResponse sr ON sr.ID = it.supplyResponseFk
LEFT JOIN edi.VMPSettings v ON v.VMPID = sr.vmpID
LEFT JOIN edi.marketPlace mp ON mp.id = sr.MarketPlaceID
LEFT JOIN (SELECT isVNHSupplier, isEarlyBird, TRUE AS itemAllowed
2024-07-22 11:34:04 +00:00
FROM addressFilter af
2024-11-27 17:19:57 +00:00
JOIN (SELECT ad.provinceFk, p.countryFk, ad.isLogifloraAllowed
FROM address ad
JOIN province p ON p.id = ad.provinceFk
WHERE ad.id = vAddressFk
) sub2 ON sub2.provinceFk <=> IFNULL(af.provinceFk, sub2.provinceFk)
AND sub2.countryFk <=> IFNULL(af.countryFk, sub2.countryFk)
AND sub2.isLogifloraAllowed <=> IFNULL(af.isLogifloraAllowed, sub2.isLogifloraAllowed)
WHERE vWarehouseFk = af.warehouseFk
AND (vShipped < af.beforeDated
OR ISNULL(af.beforeDated)
OR vShipped > af.afterDated
OR ISNULL(af.afterDated))
) sub ON sub.isVNHSupplier = v.isVNHSupplier
AND (sub.isEarlyBird = mp.isEarlyBird OR ISNULL(sub.isEarlyBird))
2024-07-22 11:34:04 +00:00
JOIN agencyMode am ON am.id = vAgencyModeFk
JOIN agency ag ON ag.id = am.agencyFk
JOIN itemType itt ON itt.id = it.typeFk
JOIN itemCategory itc on itc.id = itt.categoryFk
JOIN address ad ON ad.id = vAddressFk
2024-11-27 17:19:57 +00:00
LEFT JOIN clientItemType cit
ON cit.clientFk = ad.clientFk
AND cit.itemTypeFk = itt.id
2024-11-27 17:19:57 +00:00
LEFT JOIN zoneItemType zit
ON zit.zoneFk = vZoneFk
AND zit.itemTypeFk = itt.id
2024-11-27 17:19:57 +00:00
LEFT JOIN agencyModeItemType ait
ON ait.agencyModeFk = vAgencyModeFk
AND ait.itemTypeFk = itt.id
WHERE a.calc_id = vAvailableCalc
AND a.available > 0
AND (sub.itemAllowed OR NOT it.isFloramondo OR anr.available > 0)
AND (ag.isAnyVolumeAllowed OR NOT itt.isUnconventionalSize)
AND (it.`size` IS NULL
OR IF(itc.isReclining,
it.size <= z.itemMaxLength OR z.itemMaxLength IS NULL,
it.size <= z.itemMaxSize OR z.itemMaxSize IS NULL))
AND cit.id IS NULL
AND zit.id IS NULL
AND ait.id IS NULL;
DROP TEMPORARY TABLE tmp.buyUltimate;
2024-11-27 17:19:57 +00:00
CALL catalog_componentCalculate(vZoneFk, vAddressFk, vShipped, vWarehouseFk, vCurrencyFk);
INSERT INTO tmp.ticketCalculateItem(
itemFk,
available,
producer,
item,
size,
stems,
category,
inkFk,
image,
origin,
price,
priceKg,
2024-11-27 17:19:57 +00:00
foreignPrice,
foreignPriceKg,
`grouping`,
minQuantity)
2024-07-12 05:58:59 +00:00
SELECT tl.itemFk,
SUM(tl.available) available,
p.name producer,
i.name item,
i.size size,
i.stems,
i.category,
i.inkFk,
i.image,
o.code origin,
bl.price,
bl.priceKg,
2024-11-27 17:19:57 +00:00
currency_getRate(vCurrencyFk, NULL) * bl.price,
currency_getRate(vCurrencyFk, NULL) * bl.priceKg,
bl.`grouping`,
mq.quantity
FROM tmp.ticketLot tl
JOIN item i ON tl.itemFk = i.id
LEFT JOIN producer p ON p.id = i.producerFk AND p.isVisible
JOIN origin o ON o.id = i.originFk
JOIN (
SELECT price, itemFk, priceKg, MIN(`grouping`) `grouping`
FROM (
SELECT price, itemFk, priceKg, `grouping`
FROM tmp.ticketComponentPrice
WHERE warehouseFk = vWarehouseFk
ORDER BY (rate = 2) DESC, price
LIMIT 10000000000000000000
) sub
GROUP BY itemFk
) bl ON bl.itemFk = tl.itemFk
LEFT JOIN (
2024-07-12 12:04:49 +00:00
WITH itemMinQuantityPriority AS (
SELECT itemFk,
quantity,
ROW_NUMBER() OVER (
PARTITION BY itemFk
ORDER BY warehouseFk IS NULL
) priority
FROM vn.itemMinimumQuantity
2024-07-12 05:58:59 +00:00
WHERE `started` <= vShipped
AND (`ended` >= vShipped OR `ended` IS NULL)
2024-07-12 12:04:49 +00:00
AND (warehouseFk = vWarehouseFk OR warehouseFk IS NULL)
)
SELECT itemFk, quantity
FROM itemMinQuantityPriority
WHERE priority = 1
) mq ON mq.itemFk = tl.itemFk
2024-07-12 12:04:49 +00:00
WHERE tl.zoneFk = vZoneFk
AND tl.warehouseFk = vWarehouseFk
GROUP BY tl.itemFk
ON DUPLICATE KEY UPDATE available = available + VALUES(available);
END LOOP;
CLOSE cTravelTree;
END$$
DELIMITER ;