CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `floriday`.`offerRefresh`() BEGIN DECLARE vLanded DATETIME; DECLARE vLastInserted DATETIME; DECLARE vDayRange INT; SELECT dayRange INTO vDayRange FROM edi.offerRefreshConfig; IF vDayRange IS NULL THEN CALL util.throw("Variable vDayRange not declared"); END IF; CREATE OR REPLACE TEMPORARY TABLE offer SELECT * FROM supplyOffer; DELETE o FROM offer o LEFT JOIN vn.tag t1 ON t1.ediTypeFk = o.tag1 AND t1.overwrite = 'size' LEFT JOIN vn.tag t2 ON t2.ediTypeFk = o.tag2 AND t2.overwrite = 'size' LEFT JOIN vn.tag t3 ON t3.ediTypeFk = o.tag3 AND t3.overwrite = 'size' LEFT JOIN vn.tag t4 ON t4.ediTypeFk = o.tag4 AND t4.overwrite = 'size' LEFT JOIN vn.tag t5 ON t5.ediTypeFk = o.tag5 AND t5.overwrite = 'size' LEFT JOIN vn.tag t6 ON t6.ediTypeFk = o.tag6 AND t6.overwrite = 'size' JOIN vn.floramondoConfig fc ON TRUE WHERE (t1.id IS NOT NULL AND CONVERT(o.value1, UNSIGNED) > fc.itemMaxSize) OR (t2.id IS NOT NULL AND CONVERT(o.value2, UNSIGNED) > fc.itemMaxSize) OR (t3.id IS NOT NULL AND CONVERT(o.value3, UNSIGNED) > fc.itemMaxSize) OR (t4.id IS NOT NULL AND CONVERT(o.value4, UNSIGNED) > fc.itemMaxSize) OR (t5.id IS NOT NULL AND CONVERT(o.value5, UNSIGNED) > fc.itemMaxSize) OR (t6.id IS NOT NULL AND CONVERT(o.value6, UNSIGNED) > fc.itemMaxSize); UPDATE IGNORE offer o JOIN vn.item i ON i.name = o.vbnProductName AND i.subname <=> o.organizationName AND i.value5 <=> o.value1 AND i.value6 <=> o.value2 AND i.value7 <=> o.value3 AND i.value8 <=> o.value4 AND i.value9 <=> o.value5 AND i.value10 <=> o.value6 AND i.NumberOfItemsPerCask <=> o.piecesPerPackage AND i.EmbalageCode <=> o.packageVbnPackageCode # AND i.quality <=> o.Quality - Hasta el momento no tenemos 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 supplyLine sl ON sl.supplyLineId = i.supplyLineFk #LEFT JOIN edi.putOrder po ON po.supplyResponseID = i.supplyResponseFk #AND po.OrderTradeLineDateTime > (util.VN_CURDATE() - INTERVAL 1 WEEK) SET i.supplyLineFk = o.supplyLineId WHERE (sl.supplyLineId IS NULL OR sl.numberOfPieces = 0 OR sl.orderPeriodEndDateTime < util.VN_NOW()) AND it.isInventory AND t.id IS NULL; #AND po.id IS NULL; START TRANSACTION; CREATE OR REPLACE TEMPORARY TABLE itemToInsert ENGINE = MEMORY SELECT o.*, CAST(NULL AS DECIMAL(6,0)) itemFk FROM offer o LEFT JOIN vn.item i ON i.supplyLineFk = o.supplyLineId WHERE i.id IS NULL; INSERT INTO vn.item(id, `name`, longName, subName, expenceFk, typeFk, intrastatFk, originFk, supplyResponseFk, numberOfItemsPerCask, embalageCode, isFloriday) # NO le ponemos quality SELECT iti.itemFk, iti.vbnProductName, iti.vbnProductName, iti.organizationName, iti.expenseFk, iti.itemTypeFk, iti.intrastatFk, iti.originFk, iti.supplyLineId, iti.piecesPerPackage, iti.packageVbnPackageCode, TRUE FROM itemToInsert iti; # Inserta la foto de los articulos nuevos (prioridad alta) INSERT IGNORE INTO vn.itemImageQueue(itemFk, url) SELECT i.id, ii.imageUrl FROM itemToInsert ii JOIN vn.item i ON i.supplyLineFk = ii.supplyLineId WHERE NOT ii.imageUrl IS NULL AND i.image IS NULL; # Poner aquí insert en la supuesta tabla log # Inserción de los 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; # Inserción de los tags sólo en los articulos nuevos INSERT INTO vn.itemTag(itemFk, tagFk, value, priority) SELECT i.id, t.id, ii.vbnProductName, 1 FROM itemToInsert ii JOIN vn.tag t ON t.`name` = 'Producto' JOIN vn.item i ON i.supplyLineFk = ii.supplyLineId WHERE NOT ii.vbnProductName IS NULL; /* Por el momento, no disponemos de la quality * 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.supplyLineFk = ii.supplyLineId WHERE NOT ii.Quality IS NULL; */ INSERT INTO vn.itemTag(itemFk, tagFk, value, priority) SELECT i.id, t.id , ii.organizationName, 4 FROM itemToInsert ii JOIN vn.tag t ON t.name = 'Productor' JOIN vn.item i ON i.supplyLineFk = ii.supplyLineId WHERE NOT ii.organizationName IS NULL; INSERT INTO vn.itemTag(itemFk, tagFk, value, priority) SELECT i.id, t.id , ii.value1, 5 FROM itemToInsert ii JOIN vn.tag t ON t.ediTypeFk = ii.ef1 JOIN vn.item i ON i.supplyLineFk = ii.supplyLineId WHERE NOT ii.value1 IS NULL; INSERT INTO vn.itemTag(itemFk, tagFk, value, priority) SELECT i.id, t.id , ii.value2, 6 FROM itemToInsert ii JOIN vn.tag t ON t.ediTypeFk = ii.ef2 JOIN vn.item i ON i.supplyLineFk = ii.supplyLineId WHERE NOT ii.value2 IS NULL; INSERT INTO vn.itemTag(itemFk, tagFk, value, priority) SELECT i.id, t.id , ii.value3, 7 FROM itemToInsert ii JOIN vn.tag t ON t.ediTypeFk = ii.ef3 JOIN vn.item i ON i.supplyLineFk = ii.supplyLineId WHERE NOT ii.value3 IS NULL; INSERT INTO vn.itemTag(itemFk, tagFk, value, priority) SELECT i.id, t.id , ii.value4, 8 FROM itemToInsert ii JOIN vn.tag t ON t.ediTypeFk = ii.ef4 JOIN vn.item i ON i.supplyLineFk = ii.supplyLineId WHERE NOT ii.value4 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.supplyLineFk = ii.supplyLineId WHERE NOT s5Value IS NULL; INSERT INTO vn.itemTag(itemFk, tagFk, value, priority) SELECT i.id, t.id , ii.value5, 10 FROM itemToInsert ii JOIN vn.tag t ON t.ediTypeFk = ii.ef6 JOIN vn.item i ON i.supplyLineFk = ii.supplyLineId WHERE NOT ii.value5 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.supplyLineFk = ii.supplyLineId JOIN vn.tag t ON t.`name` = 'Color' LEFT JOIN edi.feature f ON f.item_id = ii.vbnProductCode 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; # Refresco de los tags CREATE OR REPLACE TEMPORARY TABLE tmp.item (PRIMARY KEY (id)) SELECT i.id FROM vn.item i JOIN itemToInsert ii ON i.supplyLineFk = ii.supplyLineId; CALL vn.item_refreshTags(); DROP TEMPORARY TABLE tmp.item; SELECT MIN(LatestDeliveryDateTime) INTO vLanded FROM supplyLine sl JOIN organization o ON o.organizationId = sl.organizationId JOIN edi.marketPlace mp ON mp.id = o.companyGln 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 ); # Valorar el crear floridayConfig 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 supplyLine sl ON i.supplyLineFk = sl.supplyLineId SET b.quantity = 0 WHERE (IFNULL(di.LatestOrderDateTime, util.VN_NOW()) <= util.VN_NOW() OR i.supplyLineFk IS NULL OR sl.numberOfPieces = 0) AND am.name = 'LOGIFLORA' # Crear agencia floriday AND e.isRaid; # Localiza las entradas de cada almacen (Valorar si quitar) UPDATE edi.warehouseFloramondo # warehouseFloriday? 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 # warehouseFloriday? JOIN vn.item i ON i.id = b.itemFk JOIN offer o ON i.supplyLineFk = o.supplyLineId SET b.quantity = o.numberOfPieces * o.piecesPerPackage, b.buyingValue = o.pricePerPiece WHERE (b.quantity <> o.numberOfPieces * o.piecesPerPackage OR b.buyingValue <> o.pricePerPiece); # Inserta el resto SET vLastInserted := util.VN_NOW(); # Inserta la oferta INSERT INTO vn.buy( entryFk, itemFk, quantity, buyingValue, stickers, packing, `grouping`, groupingMode, packageFk, deliveryFk) SELECT wf.entryFk, i.id, o.numberOfPieces * o.piecesPerPackage, o.Price, o.numberOfPieces, o.pricePerPiece, o.piecesPerPackage, # MinimumQuantity NO está: GREATEST(1, IFNULL(o.MinimumQuantity, 0)) * o.piecesPerPackage, 2, # Obliga al Packing o.packageVbnPackageCode, NULL # o.diId No tenemos delivery information FROM offer o JOIN vn.item i ON i.supplyResponseFk = o.srId JOIN edi.warehouseFloramondo wf # warehouseFloriday? JOIN vn.packaging p ON p.id LIKE o.packageVbnPackageCode 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 CREATE OR REPLACE TEMPORARY TABLE tmp.buyRecalc SELECT b.id FROM vn.buy b JOIN edi.warehouseFloramondo wf ON wf.entryFk = b.entryFk # warehouseFloriday? WHERE b.created >= vLastInserted; CALL vn.buy_recalcPrices(); END IF; DROP TEMPORARY TABLE 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 JOIN vn.itemType it ON it.id = i.typeFk SET typeFk = (SELECT id FROM vn.itemType WHERE code = 'GRS') WHERE i.longName LIKE 'Rosa Garden %' AND it.code = 'ROS'; UPDATE vn.item i JOIN vn.itemType it ON it.id = i.typeFk SET typeFk = (SELECT id FROM vn.itemType WHERE code = 'REC') WHERE i.longName LIKE 'Rosa ec %' AND it.code = 'ROS'; # Refresca las fotos de los items existentes que mostramos (prioridad baja) INSERT IGNORE INTO vn.itemImageQueue(itemFk, url, priority) SELECT i.id, tip.url, 100 FROM tradeItem ti JOIN tradeItemPhoto tip ON tip.tradeItemId = ti.tradeItemId JOIN supplyLine sl ON sl.tradeItemId = ti.tradeItemId AND tip.`primary` JOIN vn.item i ON i.supplyLineFk = sl.supplyLineId JOIN hedera.image i2 ON i2.name = i.image AND i2.collectionFk = 'catalog' WHERE i2.updated <= (UNIX_TIMESTAMP(util.VN_NOW()) - vDayRange) AND sl.numberOfPieces; END