DELIMITER $$ CREATE OR REPLACE DEFINER=`root`@`localhost` TRIGGER `vn`.`invoiceOut_beforeInsert` BEFORE INSERT ON `invoiceOut` FOR EACH ROW BEGIN /** * Reference format: * - 0: Serial [A-Z] * - 1: Sage company id * - 2-3: Last two digits of issued year * - 4-8: Autoincrement identifier **/ DECLARE vNewRef INT DEFAULT 0; DECLARE vCompanyCode INT; DECLARE vLastRef VARCHAR(255); DECLARE vRefStr VARCHAR(255); DECLARE vRefLen INT DEFAULT 5; DECLARE vYearLen INT DEFAULT 2; DECLARE vPrefixLen INT; SELECT companyCode INTO vCompanyCode FROM company WHERE id = NEW.companyFk; IF vCompanyCode IS NULL THEN CALL util.throw('sageCompanyNotDefined'); END IF; SELECT MAX(i.ref) INTO vLastRef FROM invoiceOut i WHERE i.serial = NEW.serial AND i.issued BETWEEN util.firstDayOfYear(NEW.issued) AND util.dayEnd(util.lastDayOfYear(NEW.issued)) AND i.companyFk = NEW.companyFk; IF vLastRef IS NOT NULL THEN SET vPrefixLen = LENGTH(NEW.serial) + LENGTH(vCompanyCode) + vYearLen; SET vRefLen = LENGTH(vLastRef) - vPrefixLen; SET vRefStr = SUBSTRING(vLastRef, vPrefixLen + 1); SET vNewRef = vRefStr + 1; IF LENGTH(vNewRef) > vRefLen THEN CALL util.throw('refLenExceeded'); END IF; SET NEW.ref = CONCAT( SUBSTRING(vLastRef, 1, vPrefixLen), LPAD(vNewRef, LENGTH(vRefStr), '0') ); ELSE SET NEW.ref = CONCAT( NEW.serial, vCompanyCode, RIGHT(YEAR(NEW.issued), vYearLen), LPAD(1, vRefLen, '0') ); END IF; END$$ DELIMITER ;