DELIMITER $$ CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `edi`.`floramondo_offerRefresh`() proc: BEGIN DECLARE vLanded DATETIME; DECLARE vDone INT DEFAULT FALSE; DECLARE vFreeId INT; DECLARE vSupplyResponseFk INT; DECLARE vLastInserted DATETIME; DECLARE vIsAuctionDay BOOLEAN; DECLARE vMaxNewItems INT DEFAULT 10000; DECLARE vStartingTime DATETIME; DECLARE vAalsmeerMarketPlaceID VARCHAR(13) DEFAULT '8713783439043'; DECLARE vDayRange INT; DECLARE cur1 CURSOR FOR SELECT id FROM edi.item_free; DECLARE cur2 CURSOR FOR SELECT srId FROM itemToInsert; DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE; DECLARE EXIT HANDLER FOR SQLSTATE '45000' BEGIN ROLLBACK; RESIGNAL; END; DECLARE CONTINUE HANDLER FOR SQLEXCEPTION BEGIN DO RELEASE_LOCK('edi.floramondo_offerRefresh'); SET @isTriggerDisabled = FALSE; RESIGNAL; END; IF 'test' = (SELECT environment FROM util.config) THEN LEAVE proc; END IF; IF !GET_LOCK('edi.floramondo_offerRefresh', 0) THEN LEAVE proc; END IF; SELECT dayRange INTO vDayRange FROM offerRefreshConfig; IF vDayRange IS NULL THEN CALL util.throw("Variable vDayRange not declared"); END IF; SET vStartingTime = util.VN_NOW(); TRUNCATE edi.offerList; INSERT INTO edi.offerList(supplier, total) SELECT v.name, COUNT(DISTINCT sr.ID) total FROM edi.supplyResponse sr JOIN edi.VMPSettings v ON v.VMPID = sr.vmpID WHERE sr.NumberOfUnits > 0 AND sr.EmbalageCode != 999 GROUP BY sr.vmpID; UPDATE edi.offerList o JOIN (SELECT v.name, COUNT(*) total FROM edi.supplyOffer sr JOIN edi.VMPSettings v ON v.VMPID = sr.vmpID GROUP BY sr.vmpID) sub ON o.supplier = sub.name SET o.`filter` = sub.total; -- Elimina de la lista de items libres aquellos que ya existen DELETE itf.* FROM edi.item_free itf JOIN vn.item i ON i.id = itf.id; CREATE OR REPLACE TEMPORARY TABLE tmp (INDEX (`Item_ArticleCode`)) ENGINE = MEMORY SELECT t.* FROM ( SELECT * FROM edi.supplyOffer ORDER BY (MarketPlaceID = vAalsmeerMarketPlaceID) DESC, NumberOfUnits DESC LIMIT 10000000000000000000) t GROUP BY t.srId; CREATE OR REPLACE TEMPORARY TABLE edi.offer (INDEX (`srID`), INDEX (`EmbalageCode`), INDEX (`ef1`), INDEX (`ef2`), INDEX (`ef3`), INDEX (`ef4`),INDEX (`ef5`), INDEX (`ef6`), INDEX (`s1Value`), INDEX (`s2Value`), INDEX (`s3Value`), INDEX (`s4Value`),INDEX (`s5Value`), INDEX (`s6Value`)) ENGINE = MEMORY SELECT so.*, ev1.type_description s1Value, ev2.type_description s2Value, ev3.type_description s3Value, ev4.type_description s4Value, ev5.type_description s5Value, ev6.type_description s6Value, eif1.feature ef1, eif2.feature ef2, eif3.feature ef3, eif4.feature ef4, eif5.feature ef5, eif6.feature ef6 FROM tmp so LEFT JOIN edi.item_feature eif1 ON eif1.item_id = so.Item_ArticleCode AND eif1.presentation_order = 1 AND eif1.expiry_date IS NULL LEFT JOIN edi.item_feature eif2 ON eif2.item_id = so.Item_ArticleCode AND eif2.presentation_order = 2 AND eif2.expiry_date IS NULL LEFT JOIN edi.item_feature eif3 ON eif3.item_id = so.Item_ArticleCode AND eif3.presentation_order = 3 AND eif3.expiry_date IS NULL LEFT JOIN edi.item_feature eif4 ON eif4.item_id = so.Item_ArticleCode AND eif4.presentation_order = 4 AND eif4.expiry_date IS NULL LEFT JOIN edi.item_feature eif5 ON eif5.item_id = so.Item_ArticleCode AND eif5.presentation_order = 5 AND eif5.expiry_date IS NULL LEFT JOIN edi.item_feature eif6 ON eif6.item_id = so.Item_ArticleCode AND eif6.presentation_order = 6 AND eif6.expiry_date IS NULL LEFT JOIN edi.`value` ev1 ON ev1.type_id = eif1.feature AND so.s1 = ev1.type_value LEFT JOIN edi.`value` ev2 ON ev2.type_id = eif2.feature AND so.s2 = ev2.type_value LEFT JOIN edi.`value` ev3 ON ev3.type_id = eif3.feature AND so.s3 = ev3.type_value LEFT JOIN edi.`value` ev4 ON ev4.type_id = eif4.feature AND so.s4 = ev4.type_value LEFT JOIN edi.`value` ev5 ON ev5.type_id = eif5.feature AND so.s5 = ev5.type_value LEFT JOIN edi.`value` ev6 ON ev6.type_id = eif6.feature AND so.s6 = ev6.type_value ORDER BY Price; DROP TEMPORARY TABLE tmp; DELETE o FROM edi.offer o LEFT JOIN vn.tag t1 ON t1.ediTypeFk = o.ef1 AND t1.overwrite = 'size' LEFT JOIN vn.tag t2 ON t2.ediTypeFk = o.ef2 AND t2.overwrite = 'size' LEFT JOIN vn.tag t3 ON t3.ediTypeFk = o.ef3 AND t3.overwrite = 'size' LEFT JOIN vn.tag t4 ON t4.ediTypeFk = o.ef4 AND t4.overwrite = 'size' LEFT JOIN vn.tag t5 ON t5.ediTypeFk = o.ef5 AND t5.overwrite = 'size' LEFT JOIN vn.tag t6 ON t6.ediTypeFk = o.ef6 AND t6.overwrite = 'size' JOIN vn.floramondoConfig fc ON TRUE WHERE (t1.id IS NOT NULL AND CONVERT(s1Value, UNSIGNED) > fc.itemMaxSize) OR (t2.id IS NOT NULL AND CONVERT(s2Value, UNSIGNED) > fc.itemMaxSize) OR (t3.id IS NOT NULL AND CONVERT(s3Value, UNSIGNED) > fc.itemMaxSize) OR (t4.id IS NOT NULL AND CONVERT(s4Value, UNSIGNED) > fc.itemMaxSize) OR (t5.id IS NOT NULL AND CONVERT(s5Value, UNSIGNED) > fc.itemMaxSize) OR (t6.id IS NOT NULL AND CONVERT(s6Value, UNSIGNED) > fc.itemMaxSize); START TRANSACTION; -- Actualizamos el campo supplyResponseFk para aquellos articulos que ya estan creados y reutilizamos UPDATE IGNORE edi.offer o JOIN vn.item i ON i.name = o.product_name AND i.subname <=> o.company_name AND i.value5 <=> o.s1Value AND i.value6 <=> o.s2Value AND i.value7 <=> o.s3Value AND i.value8 <=> o.s4Value AND i.value9 <=> o.s5Value AND i.value10 <=> o.s6Value AND i.NumberOfItemsPerCask <=> o.NumberOfItemsPerCask AND i.EmbalageCode <=> o.EmbalageCode AND i.quality <=> o.Quality JOIN vn.itemType it ON it.id = i.typeFk LEFT JOIN vn.sale s ON s.itemFk = i.id LEFT JOIN vn.ticket t ON t.id = s.ticketFk AND t.shipped > (util.VN_CURDATE() - INTERVAL 1 WEEK) LEFT JOIN edi.supplyResponse sr ON sr.ID = i.supplyResponseFk LEFT JOIN edi.deliveryInformation di ON di.supplyResponseID = sr.ID LEFT JOIN edi.putOrder po ON po.supplyResponseID = i.supplyResponseFk AND po.OrderTradeLineDateTime > (util.VN_CURDATE() - INTERVAL 1 WEEK) SET i.supplyResponseFk = o.srID WHERE (sr.ID IS NULL OR sr.NumberOfUnits = 0 OR di.LatestOrderDateTime < util.VN_NOW() OR di.ID IS NULL) AND it.isInventory AND t.id IS NULL AND po.id IS NULL; CREATE OR REPLACE TEMPORARY TABLE itemToInsert ENGINE = MEMORY SELECT o.*, CAST(NULL AS DECIMAL(6,0)) itemFk FROM edi.offer o LEFT JOIN vn.item i ON i.supplyResponseFk = o.srId WHERE i.id IS NULL LIMIT vMaxNewItems; -- Reciclado de nº de item OPEN cur1; OPEN cur2; read_loop: LOOP FETCH cur2 INTO vSupplyResponseFk; FETCH cur1 INTO vFreeId; IF vDone THEN LEAVE read_loop; END IF; UPDATE itemToInsert SET itemFk = vFreeId WHERE srId = vSupplyResponseFk; END LOOP; CLOSE cur1; CLOSE cur2; -- Insertamos todos los items en Articles de la oferta INSERT INTO vn.item(id, `name`, longName, subName, expenseFk, typeFk, intrastatFk, originFk, supplyResponseFk, numberOfItemsPerCask, embalageCode, quality, isFloramondo) SELECT iti.itemFk, iti.product_name, iti.product_name, iti.company_name, iti.expenseFk, iti.itemTypeFk, iti.intrastatFk, iti.originFk, iti.`srId`, iti.NumberOfItemsPerCask, iti.EmbalageCode, iti.Quality, TRUE FROM itemToInsert iti; -- Inserta la foto de los articulos nuevos (prioridad alta) INSERT IGNORE INTO vn.itemImageQueue(itemFk, url) SELECT i.id, PictureReference FROM itemToInsert ii JOIN vn.item i ON i.supplyResponseFk = ii.srId WHERE PictureReference IS NOT NULL AND i.image IS NULL; INSERT INTO edi.`log`(tableName, fieldName,fieldValue) SELECT 'itemImageQueue','NumImagenesPtes', COUNT(*) FROM vn.itemImageQueue WHERE attempts = 0; -- Inserta si se añadiesen tags nuevos INSERT IGNORE INTO vn.tag (name, ediTypeFk) SELECT description, type_id FROM edi.type; -- Desabilita el trigger para recalcular los tags al final SET @isTriggerDisabled = TRUE; -- Inserta los tags sólo en los articulos nuevos INSERT INTO vn.itemTag(itemFk, tagFk, value, priority) SELECT i.id, t.id , ii.product_name, 1 FROM itemToInsert ii JOIN vn.tag t ON t.`name` = 'Producto' JOIN vn.item i ON i.supplyResponseFk = ii.`srId` WHERE NOT ii.product_name IS NULL; INSERT INTO vn.itemTag(itemFk, tagFk, value, priority) SELECT i.id, t.id , ii.Quality, 3 FROM itemToInsert ii JOIN vn.tag t ON t.`name` = 'Calidad' JOIN vn.item i ON i.supplyResponseFk = ii.`srId` WHERE NOT ii.Quality IS NULL; INSERT INTO vn.itemTag(itemFk, tagFk, value, priority) SELECT i.id, t.id , ii.company_name, 4 FROM itemToInsert ii JOIN vn.tag t ON t.`name` = 'Productor' JOIN vn.item i ON i.supplyResponseFk = ii.`srId` WHERE NOT ii.company_name IS NULL; INSERT INTO vn.itemTag(itemFk, tagFk, value, priority) SELECT i.id, t.id , s1Value, 5 FROM itemToInsert ii JOIN vn.tag t ON t.ediTypeFk = ii.ef1 JOIN vn.item i ON i.supplyResponseFk = ii.`srId` WHERE NOT s1Value IS NULL; INSERT INTO vn.itemTag(itemFk, tagFk, value, priority) SELECT i.id, t.id , s2Value, 6 FROM itemToInsert ii JOIN vn.tag t ON t.ediTypeFk = ii.ef2 JOIN vn.item i ON i.supplyResponseFk = ii.`srId` WHERE NOT s2Value IS NULL; INSERT INTO vn.itemTag(itemFk, tagFk, value, priority) SELECT i.id, t.id , s3Value, 7 FROM itemToInsert ii JOIN vn.tag t ON t.ediTypeFk = ii.ef3 JOIN vn.item i ON i.supplyResponseFk = ii.`srId` WHERE NOT s3Value IS NULL; INSERT INTO vn.itemTag(itemFk, tagFk, value, priority) SELECT i.id, t.id , s4Value, 8 FROM itemToInsert ii JOIN vn.tag t ON t.ediTypeFk = ii.ef4 JOIN vn.item i ON i.supplyResponseFk = ii.`srId` WHERE NOT s4Value IS NULL; INSERT INTO vn.itemTag(itemFk, tagFk, value, priority) SELECT i.id, t.id , s5Value, 9 FROM itemToInsert ii JOIN vn.tag t ON t.ediTypeFk = ii.ef5 JOIN vn.item i ON i.supplyResponseFk = ii.`srId` WHERE NOT s5Value IS NULL; INSERT INTO vn.itemTag(itemFk, tagFk, value, priority) SELECT i.id, t.id , s6Value, 10 FROM itemToInsert ii JOIN vn.tag t ON t.ediTypeFk = ii.ef6 JOIN vn.item i ON i.supplyResponseFk = ii.`srId` WHERE NOT s6Value IS NULL; INSERT IGNORE INTO vn.itemTag(itemFk, tagFk, value, priority) SELECT i.id, t.id, IFNULL(ink.name, ik.color), 11 FROM itemToInsert ii JOIN vn.item i ON i.supplyResponseFk = ii.`srId` JOIN vn.tag t ON t.`name` = 'Color' LEFT JOIN edi.feature f ON f.item_id = ii.Item_ArticleCode LEFT JOIN edi.`type` tp ON tp.type_id = f.feature_type_id AND tp.`description` = 'Hoofdkleur 1' LEFT JOIN vn.ink ON ink.dutchCode = f.feature_value LEFT JOIN vn.itemInk ik ON ik.longName = i.longName WHERE ink.name IS NOT NULL OR ik.color IS NOT NULL; CREATE OR REPLACE TABLE tmp.item (PRIMARY KEY (id)) SELECT i.id FROM vn.item i JOIN itemToInsert ii ON i.supplyResponseFk = ii.`srId`; CALL vn.item_refreshTags(); DROP TABLE tmp.item; SELECT MIN(LatestDeliveryDateTime) INTO vLanded FROM edi.supplyResponse sr JOIN edi.deliveryInformation di ON di.supplyResponseID = sr.ID JOIN edi.marketPlace mp ON mp.id = sr.MarketPlaceID JOIN vn.floramondoConfig fc WHERE mp.isLatestOrderDateTimeRelevant AND di.LatestOrderDateTime > IF( fc.MaxLatestOrderHour > HOUR(util.VN_NOW()), util.VN_CURDATE(), util.VN_CURDATE() + INTERVAL 1 DAY); UPDATE vn.floramondoConfig SET nextLanded = vLanded WHERE vLanded IS NOT NULL; -- Elimina la oferta obsoleta UPDATE vn.buy b JOIN vn.entry e ON e.id = b.entryFk JOIN vn.travel tr ON tr.id = e.travelFk JOIN vn.agencyMode am ON am.id = tr.agencyModeFk JOIN vn.item i ON i.id = b.itemFk LEFT JOIN edi.supplyResponse sr ON i.supplyResponseFk = sr.ID LEFT JOIN edi.deliveryInformation di ON di.ID = b.deliveryFk SET b.quantity = 0 WHERE (IFNULL(di.LatestOrderDateTime,util.VN_NOW()) <= util.VN_NOW() OR i.supplyResponseFk IS NULL OR sr.NumberOfUnits = 0) AND am.name = 'LOGIFLORA' AND e.isRaid; -- Localiza las entradas de cada almacen UPDATE edi.warehouseFloramondo SET entryFk = vn.entry_getForLogiflora(vLanded + INTERVAL travellingDays DAY, warehouseFk); IF vLanded IS NOT NULL THEN -- Actualiza la oferta existente UPDATE vn.buy b JOIN edi.warehouseFloramondo wf ON wf.entryFk = b.entryFk JOIN vn.item i ON i.id = b.itemFk JOIN edi.offer o ON i.supplyResponseFk = o.`srId` SET b.quantity = o.NumberOfUnits * o.NumberOfItemsPerCask, b.buyingValue = o.price WHERE (b.quantity <> o.NumberOfUnits * o.NumberOfItemsPerCask OR b.buyingValue <> o.price); -- Inserta el resto SET vLastInserted := util.VN_NOW(); -- Inserta la oferta INSERT INTO vn.buy ( entryFk, itemFk, quantity, buyingValue, stickers, packing, `grouping`, groupingMode, packagingFk, deliveryFk) SELECT wf.entryFk, i.id, o.NumberOfUnits * o.NumberOfItemsPerCask quantity, o.Price, o.NumberOfUnits etiquetas, o.NumberOfItemsPerCask packing, GREATEST(1, IFNULL(o.MinimumQuantity,0)) * o.NumberOfItemsPerCask `grouping`, 2, -- Obliga al Packing o.embalageCode, o.diId FROM edi.offer o JOIN vn.item i ON i.supplyResponseFk = o.srId JOIN edi.warehouseFloramondo wf JOIN vn.packaging p ON p.id LIKE o.embalageCode LEFT JOIN vn.buy b ON b.itemFk = i.id AND b.entryFk = wf.entryFk WHERE b.id IS NULL; -- Quitar esta linea y mirar de crear los packages a tiempo REAL INSERT INTO vn.itemCost( itemFk, warehouseFk, cm3, cm3delivery) SELECT b.itemFk, wf.warehouseFk, @cm3 := vn.buy_getUnitVolume(b.id), IFNULL((vc.standardFlowerBox * 1000) / i.packingOut, @cm3) FROM warehouseFloramondo wf JOIN vn.volumeConfig vc JOIN vn.buy b ON b.entryFk = wf.entryFk JOIN vn.item i ON i.id = b.itemFk LEFT JOIN vn.itemCost ic ON ic.itemFk = b.itemFk AND ic.warehouseFk = wf.warehouseFk WHERE (ic.cm3 IS NULL OR ic.cm3 = 0) ON DUPLICATE KEY UPDATE cm3 = @cm3, cm3delivery = IFNULL((vc.standardFlowerBox * 1000) / i.packingOut, @cm3); CREATE OR REPLACE TEMPORARY TABLE tmp.buyRecalc SELECT b.id FROM vn.buy b JOIN warehouseFloramondo wf ON wf.entryFk = b.entryFk WHERE b.created >= vLastInserted; CALL vn.buy_recalcPrices(); UPDATE edi.offerList o JOIN (SELECT v.name, COUNT(DISTINCT b.itemFk) total FROM vn.buy b JOIN vn.item i ON i.id = b.itemFk JOIN edi.supplyResponse sr ON sr.ID = i.supplyResponseFk JOIN edi.VMPSettings v ON v.VMPID = sr.vmpID JOIN edi.warehouseFloramondo wf ON wf.entryFk = b.entryFk JOIN vn.warehouse w ON w.id = wf.warehouseFk WHERE w.name = 'VNH' AND b.quantity > 0 GROUP BY sr.vmpID) sub ON o.supplier = sub.name SET o.vnh = sub.total; UPDATE edi.offerList o JOIN (SELECT v.name, COUNT(DISTINCT b.itemFk) total FROM vn.buy b JOIN vn.item i ON i.id = b.itemFk JOIN edi.supplyResponse sr ON sr.ID = i.supplyResponseFk JOIN edi.VMPSettings v ON v.VMPID = sr.vmpID JOIN edi.warehouseFloramondo wf ON wf.entryFk = b.entryFk JOIN vn.warehouse w ON w.id = wf.warehouseFk WHERE w.name = 'ALGEMESI' AND b.quantity > 0 GROUP BY sr.vmpID) sub ON o.supplier = sub.name SET o.algemesi = sub.total; END IF; DROP TEMPORARY TABLE edi.offer, itemToInsert; SET @isTriggerDisabled = FALSE; COMMIT; -- Esto habria que pasarlo a procesos programados o trabajar con tags y dejar las familias UPDATE vn.item i SET typeFk = 121 WHERE i.longName LIKE 'Rosa Garden %' AND typeFk = 17; UPDATE vn.item i SET typeFk = 156 WHERE i.longName LIKE 'Rosa ec %' AND typeFk = 17; -- Refresca las fotos de los items existentes que mostramos (prioridad baja) INSERT IGNORE INTO vn.itemImageQueue(itemFk, url, priority) SELECT i.id, sr.PictureReference, 100 FROM edi.supplyResponse sr JOIN vn.item i ON i.supplyResponseFk = sr.ID JOIN edi.supplyOffer so ON so.srId = sr.ID JOIN hedera.image i2 ON i2.name = i.image AND i2.collectionFk = 'catalog' WHERE i2.updated <= (UNIX_TIMESTAMP(util.VN_NOW()) - vDayRange) AND sr.NumberOfUnits; INSERT INTO edi.`log` SET tableName = 'floramondo_offerRefresh', fieldName = 'Tiempo de proceso', fieldValue = TIMEDIFF(util.VN_NOW(), vStartingTime); DO RELEASE_LOCK('edi.floramondo_offerRefresh'); END$$ DELIMITER ;