DROP PROCEDURE IF EXISTS `vn`.`ticket_doRefund`; DELIMITER $$ $$ CREATE DEFINER=`root`@`localhost` PROCEDURE `vn`.`ticket_doRefund`(IN vOriginTicket INT, OUT vNewTicket INT) BEGIN DECLARE vDone BIT DEFAULT 0; DECLARE vCustomer MEDIUMINT; DECLARE vWarehouse TINYINT; DECLARE vCompany MEDIUMINT; DECLARE vAddress MEDIUMINT; DECLARE vRefundAgencyMode INT; DECLARE vItemFk INT; DECLARE vQuantity DECIMAL (10,2); DECLARE vConcept VARCHAR(50); DECLARE vPrice DECIMAL (10,2); DECLARE vDiscount TINYINT; DECLARE vSaleNew INT; DECLARE vSaleMain INT; DECLARE vZoneFk INT; DECLARE vRsMainTicket CURSOR FOR SELECT * FROM tmp.sale; DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = 1; SELECT id INTO vRefundAgencyMode FROM agencyMode WHERE `name` = 'ABONO'; SELECT clientFk, warehouseFk, companyFk, addressFk INTO vCustomer, vWarehouse, vCompany, vAddress FROM ticket WHERE id = vOriginTicket; SELECT id INTO vZoneFk FROM zone WHERE agencyModeFk = vRefundAgencyMode LIMIT 1; INSERT INTO vn.ticket ( clientFk, shipped, addressFk, agencyModeFk, nickname, warehouseFk, companyFk, landed, zoneFk ) SELECT vCustomer, CURDATE(), vAddress, vRefundAgencyMode, a.nickname, vWarehouse, vCompany, CURDATE(), vZoneFk FROM address a WHERE a.id = vAddress; SET vNewTicket = LAST_INSERT_ID(); SET vDone := 0; OPEN vRsMainTicket ; FETCH vRsMainTicket INTO vSaleMain, vItemFk, vQuantity, vConcept, vPrice, vDiscount; WHILE NOT vDone DO INSERT INTO vn.sale(ticketFk, itemFk, quantity, concept, price, discount) VALUES( vNewTicket, vItemFk, vQuantity, vConcept, vPrice, vDiscount ); SET vSaleNew = LAST_INSERT_ID(); INSERT INTO vn.saleComponent(saleFk,componentFk,`value`) SELECT vSaleNew,componentFk,`value` FROM vn.saleComponent WHERE saleFk = vSaleMain; FETCH vRsMainTicket INTO vSaleMain, vItemFk, vQuantity, vConcept, vPrice, vDiscount; END WHILE; CLOSE vRsMainTicket; INSERT INTO vn.ticketRefund(refundTicketFk, originalTicketFk) VALUES(vNewTicket, vOriginTicket); END$$ DELIMITER ; CREATE TABLE `vn`.`ticketRefund` ( `id` INT auto_increment NULL, `refundTicketFk` INT NOT NULL, `originalTicketFk` INT NOT NULL, CONSTRAINT `ticketRefund_PK` PRIMARY KEY (id) ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci; ALTER TABLE `vn`.`ticketRefund` ADD CONSTRAINT `ticketRefund_FK` FOREIGN KEY (`refundTicketFk`) REFERENCES `vn`.`ticket`(`id`) ON DELETE RESTRICT ON UPDATE CASCADE; ALTER TABLE `vn`.`ticketRefund` ADD CONSTRAINT `ticketRefund_FK_1` FOREIGN KEY (`originalTicketFk`) REFERENCES `vn`.`ticket`(`id`) ON DELETE RESTRICT ON UPDATE CASCADE; DELIMITER $$ $$ CREATE DEFINER=`root`@`localhost` TRIGGER `vn`.`ticketRefund_beforeInsert` BEFORE INSERT ON `ticketRefund` FOR EACH ROW BEGIN DECLARE vAlreadyExists BOOLEAN DEFAULT FALSE; IF NEW.refundTicketFk = NEW.originalTicketFk THEN CALL util.throw('Original ticket and refund ticket has same id'); END IF; SELECT COUNT(*) INTO vAlreadyExists FROM ticketRefund WHERE refundTicketFk = NEW.originalTicketFk; IF vAlreadyExists > 0 THEN CALL util.throw('This ticket is already a refund'); END IF; END$$ DELIMITER ; DELIMITER $$ $$ CREATE DEFINER=`root`@`localhost` TRIGGER `vn`.`ticketRefund_beforeUpdate` BEFORE UPDATE ON `ticketRefund` FOR EACH ROW BEGIN DECLARE vAlreadyExists BOOLEAN DEFAULT FALSE; IF NEW.refundTicketFk = NEW.originalTicketFk THEN CALL util.throw('Original ticket and refund ticket has same id'); END IF; SELECT COUNT(*) INTO vAlreadyExists FROM ticketRefund WHERE refundTicketFk = NEW.originalTicketFk; IF vAlreadyExists > 0 THEN CALL util.throw('This ticket is already a refund'); END IF; END$$ DELIMITER ;