DELIMITER $$ CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `edi`.`ekt_load`(IN `vSelf` INT) proc:BEGIN /** * Carga los datos esenciales para el sistema EKT. * Inserta compras y ventas si es necesario. * * @param vSelf Id de ekt */ DECLARE vRef INT; DECLARE vBuy INT; DECLARE vItem INT; DECLARE vQty INT; DECLARE vPackage INT; DECLARE vPutOrderFk INT; DECLARE vIsLot BOOLEAN; DECLARE vEntryFk INT; DECLARE vHasToChangePackagingFk BOOLEAN; DECLARE vIsFloramondoDirect BOOLEAN; DECLARE vTicketFk INT; DECLARE vHasItemGroup BOOL; DECLARE vDescription VARCHAR(255); DECLARE vSaleFk INT; DECLARE vDefaultEntry INT; -- Carga los datos necesarios del EKT SELECT e.ref, qty, package, putOrderFk MOD 1000000, i2.id , NOT ISNULL(eea.addressFk), NOT ISNULL(igto.group_code), CONCAT(e.`ref`, ' ', e.item, ' ', e.sub, ' EktFk:', e.id) INTO vRef, vQty, vPackage, vPutOrderFk, vItem, vIsFloramondoDirect, vHasItemGroup, vDescription FROM ekt e LEFT JOIN item i ON e.ref = i.id LEFT JOIN putOrder po ON po.id = e.putOrderFk LEFT JOIN vn.item i2 ON i2.supplyResponseFk = po.supplyResponseID LEFT JOIN vn.ektEntryAssign eea ON eea.sub = e.sub LEFT JOIN item_groupToOffer igto ON igto.group_code = i.group_id WHERE e.id = vSelf LIMIT 1; IF NOT vHasItemGroup THEN CALL vn.mail_insert('logistica@verdnatura.es', 'nocontestar@verdnatura.es', 'Nuevo grupo en Floramondo', vDescription); CALL vn.mail_insert('pako@verdnatura.es', 'nocontestar@verdnatura.es', CONCAT('Nuevo grupo en Floramondo: ', vDescription), vDescription); LEAVE proc; END IF; SELECT defaultEntry INTO vDefaultEntry FROM vn.entryConfig; -- Asigna la entrada SELECT vn.ekt_getEntry(vSelf) INTO vEntryFk; -- Inserta el cubo si no existe IF vPackage = 800 THEN SET vHasToChangePackagingFk = TRUE; IF vItem THEN SELECT vn.item_getPackage(vItem) INTO vPackage ; ELSE SET vPackage = 8000 + vQty; INSERT IGNORE INTO vn.packaging(id, width, `depth`) SELECT vPackage, vc.ccLength / vQty, vc.ccWidth FROM vn.volumeConfig vc; END IF; ELSE INSERT IGNORE INTO vn2008.Cubos (Id_Cubo, X, Y, Z) SELECT bucket_id, ROUND(x_size/10), ROUND(y_size/10), ROUND(z_size/10) FROM bucket WHERE bucket_id = vPackage; IF ROW_COUNT() > 0 THEN INSERT INTO vn2008.mail SET `subject` = 'Cubo añadido', `text` = CONCAT('Se ha añadido el cubo: ', vPackage), `to` = 'ekt@verdnatura.es'; END IF; END IF; -- Si es una compra de Logiflora obtiene el articulo IF vPutOrderFk THEN SELECT i.id INTO vItem FROM putOrder po JOIN vn.item i ON i.supplyResponseFk = po.supplyResponseID WHERE po.id = vPutOrderFk LIMIT 1; END IF; INSERT IGNORE INTO item_track SET item_id = vRef; IF vItem IS NULL THEN -- Intenta obtener el artículo en base a los atributos holandeses SELECT b.id, IFNULL(b.itemOriginalFk ,b.itemFk) INTO vBuy, vItem FROM ekt e JOIN item_track t ON t.item_id = e.ref LEFT JOIN ekt l ON l.ref = e.ref LEFT JOIN vn.buy b ON b.ektFk = l.id LEFT JOIN vn.item i ON i.id = b.itemFk WHERE e.id = vSelf AND l.id != vSelf AND b.itemFk != vDefaultEntry AND IF(t.s1, l.s1 = e.s1, TRUE) AND IF(t.s2, l.s2 = e.s2, TRUE) AND IF(t.s3, l.s3 = e.s3, TRUE) AND IF(t.s4, l.s4 = e.s4, TRUE) AND IF(t.s5, l.s5 = e.s5, TRUE) AND IF(t.s6, l.s6 = e.s6, TRUE) AND IF(t.pac, l.pac = e.pac, TRUE) AND IF(t.cat, l.cat = e.cat, TRUE) AND IF(t.ori, l.ori = e.ori, TRUE) AND IF(t.pro, l.pro = e.pro, TRUE) AND IF(t.package, l.package = e.package, TRUE) AND IF(t.item, l.item = e.item, TRUE) AND i.isFloramondo = vIsFloramondoDirect ORDER BY l.now DESC, b.id ASC LIMIT 1; END IF; -- Si no encuentra el articulo lo crea en el caso de las compras directas en Floramondo IF vItem IS NULL AND vIsFloramondoDirect THEN CALL item_getNewByEkt(vSelf, vItem); END IF; INSERT INTO vn.buy ( entryFk, ektFk, buyingValue, itemFk, stickers, packing, `grouping`, quantity, groupingMode, packagingFk, weight) SELECT vEntryFk, vSelf, (@t := IF(i.stems, i.stems, 1)) * e.pri / IFNULL(i.stemMultiplier, 1) buyingValue, IFNULL(vItem, vDefaultEntry) itemFk, e.qty stickers, @pac := GREATEST(1, IFNULL(i.stemMultiplier, 1) * e.pac / @t) packing, IFNULL(b.`grouping`, e.pac), @pac * e.qty, 'packing', IF(vHasToChangePackagingFk OR b.packagingFk IS NULL, vPackage, b.packagingFk), (IFNULL(i.weightByPiece, 0) * @pac) / 1000 FROM ekt e LEFT JOIN vn.buy b ON b.id = vBuy LEFT JOIN vn.item i ON i.id = b.itemFk LEFT JOIN vn.supplier s ON e.pro = s.id WHERE e.id = vSelf LIMIT 1; CREATE OR REPLACE TEMPORARY TABLE tmp.buyRecalc SELECT buy.id FROM vn.buy WHERE ektFk = vSelf; CALL vn.buy_recalcPrices(); -- Si es una compra de Logiflora hay que informar la tabla vn.saleBuy IF vPutOrderFk THEN REPLACE vn.saleBuy(saleFk, buyFk, workerFk) SELECT po.saleFk, b.id, account.myUser_getId() FROM putOrder po JOIN vn.buy b ON b.ektFk = vSelf WHERE po.id = vPutOrderFk; END IF; -- Si es una compra directa en Floramondo hay que añadirlo al ticket IF vIsFloramondoDirect THEN SELECT t.id INTO vTicketFk FROM vn.ticket t JOIN vn.ektEntryAssign eea ON eea.addressFk = t.addressFk AND t.warehouseFk = eea.warehouseInFk JOIN ekt e ON e.sub = eea.sub AND e.id = vSelf WHERE e.fec = t.shipped LIMIT 1; IF vTicketFk IS NULL THEN SET @clientFk = NULL; INSERT INTO vn.ticket ( clientFk, shipped, addressFk, agencyModeFk, nickname, warehouseFk, companyFk, landed, zoneFk, zonePrice, zoneBonus) SELECT @clientFk := a.clientFk, e.fec, a.id, a.agencyModeFk, a.nickname, eea.warehouseInFk, c.id, e.fec, z.id, z.price, z.bonus FROM ekt e JOIN vn.ektEntryAssign eea ON eea.sub = e.sub JOIN vn.address a ON a.id = eea.addressFk JOIN vn.company c ON c.code = 'VNL' JOIN vn.`zone` z ON z.code = 'FLORAMONDO' WHERE e.id = vSelf LIMIT 1; SET vTicketFk = LAST_INSERT_ID(); IF @clientFk IS NULL THEN CALL util.throw(CONCAT("Ticket creation failed: ", vSelf)); END IF; END IF; INSERT INTO vn.sale (itemFk, ticketFk, concept, quantity, price) SELECT vItem, vTicketFk, e.item, e.qty * e.pac, e.pri * ( 1 + fhc.floramondoMargin ) FROM ekt e JOIN floraHollandConfig fhc WHERE e.id = vSelf; SELECT LAST_INSERT_ID() INTO vSaleFk; REPLACE vn.saleBuy(saleFk, buyFk, workerFk) SELECT vSaleFk, b.id, account.myUser_getId() FROM vn.buy b WHERE b.ektFk = vSelf; INSERT INTO vn.saleComponent(saleFk, componentFk, value) SELECT vSaleFk, c.id, e.pri FROM ekt e JOIN vn.component c ON c.code = 'purchaseValue' WHERE e.id = vSelf; INSERT INTO vn.saleComponent(saleFk, componentFk, value) SELECT vSaleFk, c.id, e.pri * fhc.floramondoMargin FROM ekt e JOIN floraHollandConfig fhc JOIN vn.component c ON c.code = 'margin' WHERE e.id = vSelf; END IF; DROP TEMPORARY TABLE tmp.buyRecalc; END$$ DELIMITER ;