72 lines
1.7 KiB
SQL
72 lines
1.7 KiB
SQL
DELIMITER $$
|
|
CREATE OR REPLACE DEFINER=`vn`@`localhost` FUNCTION `vn`.`ekt_getEntry`(vEktFk INT)
|
|
RETURNS int(11)
|
|
NOT DETERMINISTIC
|
|
READS SQL DATA
|
|
BEGIN
|
|
/**
|
|
* Devuelve el numero de entrada para el ekt
|
|
*
|
|
* @param vEktFk Identificador de edi.ekt
|
|
*/
|
|
DECLARE vTravelFk INT;
|
|
DECLARE vEntryFk INT DEFAULT 0;
|
|
DECLARE vEntryAssignFk INT;
|
|
|
|
SELECT ea.id
|
|
INTO vEntryAssignFk
|
|
FROM edi.ekt e
|
|
JOIN vn.ektEntryAssign ea ON
|
|
IFNULL(ea.sub, e.sub) <=> e.sub AND
|
|
IFNULL(ea.kop, e.kop) <=> e.kop AND
|
|
IFNULL(ea.pro, e.pro) <=> e.pro AND
|
|
IFNULL(ea.auction, e.auction) <=> e.auction
|
|
WHERE e.id = vEktFk
|
|
ORDER BY
|
|
IF(ea.sub,1,0) * 1000 +
|
|
IF(ea.kop,1,0) * 100 +
|
|
IF(ea.pro,1,0) * 10 +
|
|
IF(ea.auction,1,0) DESC
|
|
LIMIT 1;
|
|
|
|
SET vTravelFk = vn.ekt_getTravel(vEntryAssignFk, vEktFk);
|
|
|
|
IF vTravelFk THEN
|
|
|
|
SELECT MAX(e.id)
|
|
INTO vEntryFk
|
|
FROM vn.entry e
|
|
JOIN vn.ektEntryAssign ea ON ea.id = vEntryAssignFk
|
|
WHERE e.travelFk = vTravelFk
|
|
AND e.sub <=> ea.sub
|
|
AND e.kop <=> ea.kop
|
|
AND e.pro <=> ea.pro
|
|
AND e.auction <=> ea.auction
|
|
AND e.companyFk <=> ea.companyFk;
|
|
|
|
IF vEntryFk IS NULL THEN
|
|
INSERT INTO vn.entry(travelFk, supplierFk, companyFk, currencyFk, kop, sub, reference, pro, auction)
|
|
SELECT vTravelFk, ea.supplierFk, ea.companyFk, cu.id, ea.kop, ea.sub, ea.ref, ea.pro, ea.auction
|
|
FROM vn.ektEntryAssign ea
|
|
JOIN vn.currency cu ON cu.code = 'EUR'
|
|
WHERE ea.id = vEntryAssignFk;
|
|
|
|
SET vEntryFk = LAST_INSERT_ID();
|
|
END IF;
|
|
|
|
UPDATE vn.ektEntryAssign
|
|
SET entryFk = vEntryFk
|
|
WHERE id = vEntryAssignFk;
|
|
|
|
ELSE
|
|
|
|
SELECT ec.defaultEntry INTO vEntryFk
|
|
FROM vn.entryConfig ec;
|
|
|
|
INSERT IGNORE INTO vn.entry(id) VALUES(vEntryFk);
|
|
END IF;
|
|
|
|
RETURN vEntryFk;
|
|
END$$
|
|
DELIMITER ;
|