DELIMITER $$ CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`catalog_calculate`( vLanded DATE, vAddressFk INT, vAgencyModeFk INT, vShowExpiredZones BOOLEAN) 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 */ 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; 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(); CREATE OR REPLACE TEMPORARY TABLE tmp.ticketCalculateItem( itemFk INT(11) NOT NULL, available INT(11), producer VARCHAR(50), item VARCHAR(50), size INT(10) UNSIGNED, stems INT(11), category VARCHAR(3), inkFk VARCHAR(3), image VARCHAR(50), origin VARCHAR(3), price DECIMAL(10,2), priceKg DECIMAL(10,2), `grouping` INT(10) UNSIGNED, minQuantity INT(10) UNSIGNED, PRIMARY KEY `itemFk` (`itemFk`) ) 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 `cache`.availableNoRaids_refresh(vAvailableNoRaidsCalc, FALSE, vWarehouseFk, vShipped); 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 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 JOIN item it ON it.id = i.itemFk JOIN `zone` z ON z.id = vZoneFk 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 FROM addressFilter af 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)) 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 LEFT JOIN clientItemType cit ON cit.clientFk = ad.clientFk AND cit.itemTypeFk = itt.id LEFT JOIN zoneItemType zit ON zit.zoneFk = vZoneFk AND zit.itemTypeFk = itt.id 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; CALL catalog_componentCalculate(vZoneFk, vAddressFk, vShipped, vWarehouseFk); INSERT INTO tmp.ticketCalculateItem( itemFk, available, producer, item, size, stems, category, inkFk, image, origin, price, priceKg, `grouping`, minQuantity) 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, 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 ( WITH itemMinQuantityPriority AS ( SELECT itemFk, quantity, ROW_NUMBER() OVER ( PARTITION BY itemFk ORDER BY warehouseFk IS NULL ) priority FROM vn.itemMinimumQuantity WHERE `started` <= vShipped AND (`ended` >= vShipped OR `ended` IS NULL) AND (warehouseFk = vWarehouseFk OR warehouseFk IS NULL) ) SELECT itemFk, quantity FROM itemMinQuantityPriority WHERE priority = 1 ) mq ON mq.itemFk = tl.itemFk 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 ;