118 lines
3.3 KiB
SQL
118 lines
3.3 KiB
SQL
DROP procedure IF EXISTS `vn`.`catalog_calculate`;
|
|
|
|
DELIMITER $$
|
|
CREATE DEFINER=`root`@`%` PROCEDURE `vn`.`catalog_calculate`(
|
|
vLanded DATE,
|
|
vAddressFk INT,
|
|
vAgencyModeFk INT)
|
|
proc: BEGIN
|
|
/**
|
|
* 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
|
|
* @return tmp.ticketCalculateItem(itemFk, available, producer,
|
|
* item, size, stems, category, inkFk, image, origin, price)
|
|
* @return tmp.ticketLot(warehouseFk, itemFk, available, buyFk)
|
|
* @return tmp.ticketComponent
|
|
* @return tmp.ticketComponentPrice
|
|
* @return tmp.zoneGetShipped
|
|
|
|
**/
|
|
|
|
DECLARE vAvailableCalc INT;
|
|
DECLARE vShipped DATE;
|
|
DECLARE vClient INT;
|
|
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;
|
|
|
|
-- Establece los almacenes y las fechas que van a entrar al disponible
|
|
|
|
SELECT clientFk INTO vClient
|
|
FROM address WHERE id = vAddressFk;
|
|
|
|
CALL vn.zoneGetShippedWarehouse(vLanded, vAddressFk, vAgencyModeFk);
|
|
|
|
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',
|
|
KEY `itemFk` (`itemFk`),
|
|
KEY `item_warehouse` (`itemFk`,`warehouseFk`) USING HASH
|
|
) ENGINE=MEMORY DEFAULT CHARSET=utf8;
|
|
|
|
OPEN cTravelTree;
|
|
|
|
l: LOOP
|
|
SET vDone = FALSE;
|
|
FETCH cTravelTree INTO vZoneFk, vWarehouseFk, vShipped;
|
|
|
|
IF vDone THEN
|
|
LEAVE l;
|
|
END IF;
|
|
|
|
CALL `cache`.available_refresh (vAvailableCalc, FALSE, vWarehouseFk, vShipped);
|
|
CALL buyUltimate (vWarehouseFk, vShipped);
|
|
|
|
INSERT INTO tmp.ticketLot (warehouseFk, itemFk, available, buyFk)
|
|
SELECT vWarehouseFk,
|
|
i.item_id,
|
|
IFNULL(i.available, 0),
|
|
bu.buyFk
|
|
FROM `cache`.available i
|
|
JOIN tmp.item br ON br.itemFk = i.item_id
|
|
LEFT JOIN item it ON it.id = i.item_id
|
|
LEFT JOIN tmp.buyUltimate bu ON bu.itemFk = i.item_id
|
|
WHERE i.calc_id = vAvailableCalc
|
|
AND it.id != 100
|
|
AND i.available > 0;
|
|
|
|
DROP TEMPORARY TABLE tmp.buyUltimate;
|
|
END LOOP;
|
|
|
|
CLOSE cTravelTree;
|
|
|
|
CALL vn.catalog_componentCalculate(vZoneFk, vAddressFk, vShipped);
|
|
|
|
DROP TEMPORARY TABLE IF EXISTS tmp.ticketCalculateItem;
|
|
CREATE TEMPORARY TABLE tmp.ticketCalculateItem
|
|
ENGINE = MEMORY
|
|
SELECT
|
|
b.itemFk,
|
|
SUM(b.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
|
|
FROM tmp.ticketLot b
|
|
JOIN item i ON b.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 MIN(price) price, itemFk, priceKg
|
|
FROM tmp.ticketComponentPrice
|
|
GROUP BY itemFk
|
|
) bl ON bl.itemFk = b.itemFk
|
|
GROUP BY b.itemFk;
|
|
|
|
END$$
|
|
|
|
DELIMITER ;
|
|
|