DELIMITER $$ CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `hedera`.`order_confirmWithUser`( vSelf INT, vUserFk INT ) BEGIN /** * Confirms an order, creating each of its tickets * on the corresponding date, store and user. * * @param vSelf The order identifier * @param vUser The user identifier */ DECLARE vIsOk BOOL; DECLARE vDone BOOL; DECLARE vWarehouseFk INT; DECLARE vShipment DATE; DECLARE vTicketFk INT; DECLARE vNotes VARCHAR(255); DECLARE vItemFk INT; DECLARE vConcept VARCHAR(30); DECLARE vAmount INT; DECLARE vPrice DECIMAL(10,2); DECLARE vSaleFk INT; DECLARE vRate INT; DECLARE vRowFk INT; DECLARE vPriceFixed DECIMAL(10,2); DECLARE vLanded DATE; DECLARE vAddressFk INT; DECLARE vIsConfirmed BOOL; DECLARE vClientFk INT; DECLARE vCompanyFk INT; DECLARE vAgencyModeFk INT; DECLARE vCalcFk INT; DECLARE vIsLogifloraItem BOOL; DECLARE vIsTaxDataChecked BOOL; DECLARE vAvailable INT; DECLARE vItemPackingTypeFk VARCHAR(1); DECLARE vCountDistinctItemPackingTypeFk INT; DECLARE vDates CURSOR FOR SELECT zgs.shipped, r.warehouseFk FROM `order` o JOIN orderRow r ON r.orderFk = o.id LEFT JOIN tmp.zoneGetShipped zgs ON zgs.warehouseFk = r.warehouseFk WHERE o.id = vSelf AND r.amount GROUP BY r.warehouseFk; DECLARE vDistinctItemPackingType CURSOR FOR SELECT DISTINCT i.itemPackingTypeFk FROM `order` o JOIN orderRow r ON r.orderFk = o.id JOIN vn.item i ON i.id = r.itemFk WHERE o.id = vSelf AND r.warehouseFk = vWarehouseFk AND r.amount ORDER BY i.itemPackingTypeFk DESC; -- El último siempre NULL, es imprescindible para la lógica !!! DECLARE vRows CURSOR FOR SELECT r.id, r.itemFk, i.name, r.amount, r.price, r.rate, i.itemPackingTypeFk, i.isFloramondo FROM orderRow r JOIN vn.item i ON i.id = r.itemFk WHERE r.amount AND r.warehouseFk = vWarehouseFk AND r.orderFk = vSelf ORDER BY r.rate DESC; DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE; DECLARE EXIT HANDLER FOR SQLEXCEPTION BEGIN ROLLBACK; RESIGNAL; END; -- Carga los datos del pedido SELECT o.date_send, o.address_id, o.note, a.clientFk, o.company_id, o.agency_id, c.isTaxDataChecked INTO vLanded, vAddressFk, vNotes, vClientFk, vCompanyFk, vAgencyModeFk, vIsTaxDataChecked FROM `order` o JOIN vn.address a ON a.id = o.address_id JOIN vn.client c ON c.id = a.clientFk WHERE o.id = vSelf; -- Verifica si el cliente tiene los datos comprobados IF NOT vIsTaxDataChecked THEN CALL util.throw('clientNotVerified'); END IF; -- Carga las fechas de salida de cada almacen CALL vn.zone_getShipped(vLanded, vAddressFk, vAgencyModeFk, FALSE); -- Trabajador que realiza la accion IF vUserFk IS NULL THEN SELECT employeeFk INTO vUserFk FROM orderConfig; END IF; START TRANSACTION; CALL order_checkEditable(vSelf); -- Check order is not empty SELECT COUNT(*) > 0 INTO vIsOk FROM orderRow WHERE orderFk = vSelf AND amount > 0; IF NOT vIsOk THEN CALL util.throw('ORDER_EMPTY'); END IF; -- Crea los tickets del pedido OPEN vDates; lDates: LOOP SET vTicketFk = NULL; SET vDone = FALSE; FETCH vDates INTO vShipment, vWarehouseFk; IF vDone THEN LEAVE lDates; END IF; CREATE OR REPLACE TEMPORARY TABLE tTicketByItemPackingType( itemPackingTypeFk VARCHAR(1), ticketFk INT, PRIMARY KEY(itemPackingTypeFk, ticketFk) ) ENGINE = MEMORY; -- Busca un ticket existente que coincida con los parametros OPEN vDistinctItemPackingType; lDistinctItemPackingType: LOOP SET vItemPackingTypeFk = NULL; SET vDone = FALSE; FETCH vDistinctItemPackingType INTO vItemPackingTypeFk; IF vDone THEN LEAVE lDistinctItemPackingType; END IF; IF vItemPackingTypeFk IS NULL THEN SELECT COUNT(*) INTO vCountDistinctItemPackingTypeFk FROM tTicketByItemPackingType; CASE WHEN vCountDistinctItemPackingTypeFk = 1 THEN INSERT INTO tTicketByItemPackingType SET itemPackingTypeFk = vItemPackingTypeFk, ticketFk = (SELECT ticketFk FROM tTicketByItemPackingType); LEAVE lDistinctItemPackingType; WHEN vCountDistinctItemPackingTypeFk > 1 THEN INSERT INTO tTicketByItemPackingType SET itemPackingTypeFk = vItemPackingTypeFk, ticketFk = ( SELECT ticketFk FROM tTicketByItemPackingType WHERE itemPackingTypeFk = 'H' ); LEAVE lDistinctItemPackingType; END CASE; END IF; WITH tPrevia AS ( SELECT DISTINCT s.ticketFk FROM vn.sale s JOIN vn.saleGroupDetail sgd ON sgd.saleFk = s.id JOIN vn.ticket t ON t.id = s.ticketFk WHERE t.shipped BETWEEN vShipment AND util.dayend(vShipment) ), tTicketSameItemPackingType AS ( SELECT t.id, COUNT(*) = SUM(IF( vItemPackingTypeFk IS NOT NULL, i.itemPackingTypeFk = vItemPackingTypeFk, i.itemPackingTypeFk IS NULL )) hasSameItemPackingType FROM ticket t JOIN sale s ON s.ticketFk = t.id JOIN item i ON i.id = s.itemFk WHERE t.shipped = vShipment GROUP BY t.id HAVING hasSameItemPackingType ) SELECT t.id INTO vTicketFk FROM vn.ticket t JOIN vn.alertLevel al ON al.code = 'FREE' LEFT JOIN tPrevia tp ON tp.ticketFk = t.id LEFT JOIN vn.ticketState tls on tls.ticketFk = t.id JOIN hedera.`order` o ON o.address_id = t.addressFk AND t.warehouseFk = vWarehouseFk AND o.date_send = t.landed AND DATE(t.shipped) = vShipment JOIN tTicketSameItemPackingType tt ON tt.id = t.id WHERE o.id = vSelf AND t.refFk IS NULL AND tp.ticketFk IS NULL AND (tls.alertLevel IS NULL OR tls.alertLevel = al.id) LIMIT 1; -- Crea el ticket en el caso de no existir uno adecuado IF vTicketFk IS NULL THEN SET vShipment = IFNULL(vShipment, util.VN_CURDATE()); CALL vn.ticket_add( vClientFk, vShipment, vWarehouseFk, vCompanyFk, vAddressFk, vAgencyModeFk, NULL, vLanded, vUserFk, TRUE, vTicketFk ); ELSE INSERT INTO vn.ticketTracking SET ticketFk = vTicketFk, userFk = vUserFk, stateFk = (SELECT id FROM vn.state WHERE code = 'FREE'); END IF; INSERT IGNORE INTO vn.orderTicket SET orderFk = vSelf, ticketFk = vTicketFk; -- Añade las notas IF vNotes IS NOT NULL AND vNotes <> '' THEN INSERT INTO vn.ticketObservation SET ticketFk = vTicketFk, observationTypeFk = (SELECT id FROM vn.observationType WHERE code = 'salesPerson'), `description` = vNotes ON DUPLICATE KEY UPDATE `description` = CONCAT(VALUES(`description`),'. ', `description`); END IF; INSERT INTO tTicketByItemPackingType SET itemPackingTypeFk = vItemPackingTypeFk, ticketFk = vTicketFk; END LOOP; CLOSE vDistinctItemPackingType; -- Añade los movimientos y sus componentes OPEN vRows; lRows: LOOP SET vSaleFk = NULL; SET vDone = FALSE; FETCH vRows INTO vRowFk, vItemFk, vConcept, vAmount, vPrice, vRate, vItemPackingTypeFk, vIsLogifloraItem; IF vDone THEN LEAVE lRows; END IF; SELECT ticketFk INTO vTicketFk FROM tTicketByItemPackingType WHERE IF(vItemPackingTypeFk IS NOT NULL, itemPackingTypeFk = vItemPackingTypeFk, itemPackingTypeFk IS NULL) SELECT s.id INTO vSaleFk FROM vn.sale s WHERE ticketFk = vTicketFk AND price = vPrice AND itemFk = vItemFk AND discount = 0 LIMIT 1; IF vSaleFk THEN UPDATE vn.sale SET quantity = quantity + vAmount, originalQuantity = quantity WHERE id = vSaleFk; ELSE -- Obtiene el coste SELECT SUM(rc.`price`) valueSum INTO vPriceFixed FROM orderRowComponent rc JOIN vn.component c ON c.id = rc.componentFk JOIN vn.componentType ct ON ct.id = c.typeFk AND ct.isBase WHERE rc.rowFk = vRowFk; INSERT INTO vn.sale SET itemFk = vItemFk, ticketFk = vTicketFk, concept = vConcept, quantity = vAmount, price = vPrice, priceFixed = vPriceFixed, isPriceFixed = TRUE; SET vSaleFk = LAST_INSERT_ID(); INSERT INTO vn.saleComponent (saleFk, componentFk, `value`) SELECT vSaleFk, rc.componentFk, rc.price FROM orderRowComponent rc JOIN vn.component c ON c.id = rc.componentFk WHERE rc.rowFk = vRowFk GROUP BY vSaleFk, rc.componentFk; END IF; UPDATE orderRow SET saleFk = vSaleFk WHERE id = vRowFk; -- Inserta en putOrder si la compra es de Floramondo IF vIsLogifloraItem THEN CALL cache.availableNoRaids_refresh(vCalcFk, FALSE,vWarehouseFk, vShipment); SELECT GREATEST(0, available) INTO vAvailable FROM cache.availableNoRaids WHERE calc_id = vCalcFk AND item_id = vItemFk; UPDATE cache.availableNoRaids SET available = GREATEST(0, available - vAmount) WHERE item_id = vItemFk AND calc_id = vCalcFk; INSERT INTO edi.putOrder ( deliveryInformationID, supplyResponseId, quantity , EndUserPartyId, EndUserPartyGLN, FHAdminNumber, saleFk ) SELECT di.ID, i.supplyResponseFk, CEIL((vAmount - vAvailable)/ sr.NumberOfItemsPerCask), o.address_id , vClientFk, IFNULL(ca.fhAdminNumber, fhc.defaultAdminNumber), vSaleFk FROM edi.deliveryInformation di JOIN vn.item i ON i.supplyResponseFk = di.supplyResponseID JOIN edi.supplyResponse sr ON sr.ID = i.supplyResponseFk LEFT JOIN edi.clientFHAdminNumber ca ON ca.clientFk = vClientFk JOIN edi.floraHollandConfig fhc JOIN `order` o ON o.id = vSelf WHERE i.id = vItemFk AND di.LatestOrderDateTime > util.VN_NOW() AND vAmount > vAvailable LIMIT 1; END IF; END LOOP; CLOSE vRows; END LOOP; CLOSE vDates; UPDATE `order` SET confirmed = TRUE, confirm_date = util.VN_NOW() WHERE id = vSelf; COMMIT; DROP TEMPORARY TABLE tTicketByItemPackingType; END$$ DELIMITER ;