DELIMITER $$ CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`ticket_cloneWeekly`(vDateFrom DATE, vDateTo DATE) BEGIN DECLARE vIsDone BOOL; DECLARE vLanding DATE; DECLARE vShipment DATE; DECLARE vWarehouseFk INT; DECLARE vTicketFk INT; DECLARE vClientFk INT; DECLARE vCompanyFk INT; DECLARE vAddressFk INT; DECLARE vAgencyModeFk INT; DECLARE vNewTicket INT; DECLARE vYear INT; DECLARE vSalesPersonFK INT; DECLARE vItemPicker INT; DECLARE rsTicket CURSOR FOR SELECT tt.ticketFk, t.clientFk, t.warehouseFk, t.companyFk, t.addressFk, tt.agencyModeFk, ti.dated FROM ticketWeekly tt JOIN ticket t ON tt.ticketFk = t.id JOIN tmp.time ti WHERE WEEKDAY(ti.dated) = tt.weekDay; DECLARE CONTINUE HANDLER FOR NOT FOUND SET vIsDone = TRUE; CALL `util`.`time_generate`(vDateFrom,vDateTo); OPEN rsTicket; myLoop: LOOP BEGIN DECLARE vSalesPersonEmail VARCHAR(150); DECLARE vIsDuplicateMail BOOL; DECLARE vSubject VARCHAR(150); DECLARE vMessage TEXT; SET vIsDone = FALSE; FETCH rsTicket INTO vTicketFk,vClientFk, vWarehouseFk, vCompanyFk, vAddressFk, vAgencyModeFk,vShipment; IF vIsDone THEN LEAVE myLoop; END IF; -- busca si el ticket ya ha sido clonado IF EXISTS (SELECT TRUE FROM ticket tOrig JOIN sale saleOrig ON tOrig.id = saleOrig.ticketFk JOIN saleCloned sc ON sc.saleOriginalFk = saleOrig.id JOIN sale saleClon ON saleClon.id = sc.saleClonedFk JOIN ticket tClon ON tClon.id = saleClon.ticketFk WHERE tOrig.id = vTicketFk AND tClon.isDeleted = FALSE AND DATE(tClon.shipped) = vShipment) THEN ITERATE myLoop; END IF; IF vAgencyModeFk IS NULL THEN SELECT agencyModeFk INTO vAgencyModeFk FROM address WHERE clientFk = vClientFk AND isDefaultAddress; END IF; CALL zone_getLanded(vShipment, vAddressFk, vAgencyModeFk, vWarehouseFk,FALSE); SET vLanding = NULL; SELECT landed INTO vLanding FROM tmp.zoneGetLanded LIMIT 1; CALL ticket_add( vClientFk, vShipment, vWarehouseFk, vCompanyFk, vAddressFk, vAgencyModeFk, NULL, vLanding, account.myUser_getId(), FALSE, vNewTicket); UPDATE ticket SET clonedFrom = vTicketFk WHERE id = vNewTicket; INSERT INTO sale (ticketFk, itemFk, concept, quantity, price, discount, priceFixed, isPriceFixed) SELECT vNewTicket, saleOrig.itemFk, saleOrig.concept, saleOrig.quantity, saleOrig.price, saleOrig.discount, saleOrig.priceFixed, saleOrig.isPriceFixed FROM sale saleOrig WHERE saleOrig.ticketFk = vTicketFk; INSERT IGNORE INTO saleCloned(saleOriginalFk, saleClonedFk) SELECT saleOriginal.id, saleClon.id FROM sale saleOriginal JOIN sale saleClon ON saleOriginal.itemFk = saleClon.itemFk AND saleOriginal.quantity = saleClon.quantity WHERE saleOriginal.ticketFk = vTicketFk AND saleClon.ticketFk = vNewTicket; INSERT INTO ticketRequest (description, ordered, shipped, quantity, price, itemFk, clientFk, response, total, buyed, requesterFk ,attenderFk, ticketFk) SELECT description, ordered, shipped, quantity, price, itemFk, clientFk, response, total, buyed, requesterFk, attenderFk, vNewTicket FROM ticketRequest WHERE ticketFk =vTicketFk; SELECT id INTO vSalesPersonFK FROM observationType WHERE code = 'salesPerson'; SELECT id INTO vItemPicker FROM observationType WHERE code = 'itemPicker'; INSERT INTO ticketObservation( ticketFk, observationTypeFk, description) VALUES( vNewTicket, vSalesPersonFK, CONCAT('turno desde ticket: ',vTicketFk)) ON DUPLICATE KEY UPDATE description = CONCAT(ticketObservation.description,VALUES(description),' '); INSERT INTO ticketObservation(ticketFk, observationTypeFk, description) VALUES( vNewTicket, vItemPicker, 'ATENCION: Contiene lineas de TURNO') ON DUPLICATE KEY UPDATE description = CONCAT(ticketObservation.description,VALUES(description),' '); IF (vLanding IS NULL) THEN SELECT e.email INTO vSalesPersonEmail FROM client c JOIN account.emailUser e ON e.userFk = c.salesPersonFk WHERE c.id = vClientFk; SET vSubject = CONCAT('Turnos - No se ha podido clonar correctamente el ticket ', vTicketFk,' para el dia: ', vShipment); SET vMessage = CONCAT('No se ha podido clonar el ticket ', vTicketFk, ' para el dia: ', vShipment, ' porque no hay una zona de envĂ­o disponible. Se ha creado el ticket: ', vNewTicket, ' pero ha que revisar las fechas y la agencia'); SELECT COUNT(*) INTO vIsDuplicateMail FROM mail WHERE receiver = vSalesPersonEmail AND subject = vSubject; IF NOT vIsDuplicateMail THEN CALL mail_insert(vSalesPersonEmail, NULL, vSubject, vMessage); END IF; CALL ticketStateUpdate (vNewTicket, 'FIXING'); ELSE CALL ticketCalculateClon(vNewTicket, vTicketFk); END IF; END; END LOOP; CLOSE rsTicket; DROP TEMPORARY TABLE IF EXISTS tmp.time; END$$ DELIMITER ;