Change delivery_part triggers to raise exception on invalid kgnr/hkid combination

This commit is contained in:
2023-05-24 14:26:09 +02:00
parent 2306ccc512
commit bde7ba2971

View File

@ -526,29 +526,35 @@ CREATE TABLE delivery_part (
) STRICT;
CREATE TRIGGER t_delivery_part_i
AFTER INSERT ON delivery_part FOR EACH ROW
BEFORE INSERT ON delivery_part FOR EACH ROW
WHEN NEW.kgnr IS NOT NULL
BEGIN
UPDATE delivery_part SET hkid = (
SELECT hkid
FROM wb_kg wk
SELECT RAISE(ABORT, 'Invalid kgnr and hkid combination')
WHERE 0 = (
SELECT COUNT(*) FROM wb_kg wk
JOIN AT_kg k ON wk.kgnr = k.kgnr
JOIN wb_gem wg ON wg.gkz = k.gkz
WHERE wk.kgnr = NEW.kgnr
) WHERE (year, did, dpnr) = (NEW.year, NEW.did, NEW.dpnr);
LEFT JOIN wine_origin wo1 ON wg.hkid = wo1.hkid
LEFT JOIN wine_origin wo2 ON wo1.parent_hkid = wo2.hkid
LEFT JOIN wine_origin wo3 ON wo2.parent_hkid = wo3.hkid
LEFT JOIN wine_origin wo4 ON wo3.parent_hkid = wo4.hkid
WHERE wk.kgnr = NEW.kgnr AND NEW.hkid IN (wo1.hkid, wo2.hkid, wo3.hkid, wo4.hkid));
END;
CREATE TRIGGER t_delivery_part_u
AFTER UPDATE OF kgnr ON delivery_part FOR EACH ROW
BEFORE UPDATE ON delivery_part FOR EACH ROW
WHEN NEW.kgnr IS NOT NULL
BEGIN
UPDATE delivery_part SET hkid = (
SELECT hkid
FROM wb_kg wk
SELECT RAISE(ABORT, 'Invalid kgnr and hkid combination')
WHERE 0 = (
SELECT COUNT(*) FROM wb_kg wk
JOIN AT_kg k ON wk.kgnr = k.kgnr
JOIN wb_gem wg ON wg.gkz = k.gkz
WHERE wk.kgnr = NEW.kgnr
) WHERE (year, did, dpnr) = (NEW.year, NEW.did, NEW.dpnr);
LEFT JOIN wine_origin wo1 ON wg.hkid = wo1.hkid
LEFT JOIN wine_origin wo2 ON wo1.parent_hkid = wo2.hkid
LEFT JOIN wine_origin wo3 ON wo2.parent_hkid = wo3.hkid
LEFT JOIN wine_origin wo4 ON wo3.parent_hkid = wo4.hkid
WHERE wk.kgnr = NEW.kgnr AND NEW.hkid IN (wo1.hkid, wo2.hkid, wo3.hkid, wo4.hkid));
END;
CREATE TABLE delivery_part_attribute (