salix/db/routines/vn/triggers/invoiceIn_beforeInsert.sql

57 lines
1.9 KiB
SQL

DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` TRIGGER `vn`.`invoiceIn_beforeInsert`
BEFORE INSERT ON `invoiceIn`
FOR EACH ROW
BEGIN
DECLARE vSerie CHAR(1) DEFAULT 'R';
DECLARE vNumReceived INT;
DECLARE vIssuingCountry, vhostCountry INT;
DECLARE vActive TINYINT;
DECLARE vWithholdingSageFk INT;
IF NOT util.string_checkPrintableAndSpanishChars(NEW.supplierRef) THEN
CALL util.throw('The invoiceIn cannot contain special characters');
END IF;
SET NEW.editorFk = account.myUser_getId();
SELECT withholdingSageFk INTO vWithholdingSageFk
FROM vn.supplier
WHERE id = NEW.supplierFk;
SET NEW.withholdingSageFk = vWithholdingSageFk;
SELECT countryFk, isActive INTO vIssuingCountry, vActive
FROM vn.supplier
WHERE id = NEW.supplierFk;
SELECT countryFk INTO vhostCountry
FROM vn.supplier
WHERE id = NEW.companyFk;
IF vActive = 0 THEN
CALL util.throw('INACTIVE_PROVIDER');
END IF;
IF (SELECT COUNT(*) FROM vn.invoiceIn
WHERE supplierRef = NEW.supplierRef
AND supplierFk = NEW.supplierFk
AND YEAR(issued) = YEAR(NEW.issued)
) THEN
CALL util.throw('reference duplicated');
END IF;
SELECT CASE WHEN (SELECT account FROM vn.supplier where id = NEW.supplierFk) LIKE '___3______' THEN 'C'
WHEN (SELECT vIssuingCountry=vhostCountry from vn.country p1 join vn.country p2 ON p2.id = vhostCountry AND p1.id = vIssuingCountry
where p1.CEE < 2 and p2.CEE < 2) = 1 THEN 'R'
WHEN (SELECT vIssuingCountry <> vhostCountry from vn.country p1 join vn.country p2 ON p2.id = vhostCountry AND p1.id = vIssuingCountry
where p1.CEE < 2 and p2.CEE < 2) = 1 THEN 'E'
WHEN (SELECT vIssuingCountry<>vhostCountry from vn.country p1 join vn.country p2 ON p2.id = vhostCountry AND p1.id = vIssuingCountry
where NOT p1.CEE < 2 AND not p1.id = 1) = 1 THEN 'W'
END INTO vSerie;
SET NEW.serial = IFNULL(vSerie,'R');
END$$
DELIMITER ;