Add triggers for adding package update rows

This will be done instead of doing this logic at the application level,
which has some subtle race conditions. When two simultaneous threads
attempt to delete the same package, two update rows for the delete
action are inserted. When done at the database level, we can ensure a
one-to-one mapping between row operations and entries in this table.

Signed-off-by: Dan McGee <dan@archlinux.org>
This commit is contained in:
Dan McGee 2012-07-07 16:50:06 -05:00
parent a87da032cb
commit 4cd588ae89
2 changed files with 75 additions and 0 deletions

View File

@ -0,0 +1,45 @@
CREATE OR REPLACE FUNCTION packages_on_insert() RETURNS trigger AS $body$
BEGIN
INSERT INTO packages_update
(action_flag, created, package_id, arch_id, repo_id, pkgname, pkgbase, new_pkgver, new_pkgrel, new_epoch)
VALUES (1, now(), NEW.id, NEW.arch_id, NEW.repo_id, NEW.pkgname, NEW.pkgbase, NEW.pkgver, NEW.pkgrel, NEW.epoch);
RETURN NULL;
END;
$body$ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION packages_on_update() RETURNS trigger AS $body$
BEGIN
INSERT INTO packages_update
(action_flag, created, package_id, arch_id, repo_id, pkgname, pkgbase, old_pkgver, old_pkgrel, old_epoch, new_pkgver, new_pkgrel, new_epoch)
VALUES (2, now(), NEW.id, NEW.arch_id, NEW.repo_id, NEW.pkgname, NEW.pkgbase, OLD.pkgver, OLD.pkgrel, OLD.epoch, NEW.pkgver, NEW.pkgrel, NEW.epoch);
RETURN NULL;
END;
$body$ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION packages_on_delete() RETURNS trigger AS $body$
BEGIN
INSERT INTO packages_update
(action_flag, created, arch_id, repo_id, pkgname, pkgbase, old_pkgver, old_pkgrel, old_epoch)
VALUES (3, now(), OLD.arch_id, OLD.repo_id, OLD.pkgname, OLD.pkgbase, OLD.pkgver, OLD.pkgrel, OLD.epoch);
RETURN NULL;
END;
$body$ LANGUAGE plpgsql;
DROP TRIGGER IF EXISTS packages_insert ON packages;
CREATE TRIGGER packages_insert
AFTER INSERT ON packages
FOR EACH ROW
EXECUTE PROCEDURE packages_on_insert();
DROP TRIGGER IF EXISTS packages_update ON packages;
CREATE TRIGGER packages_update
AFTER UPDATE ON packages
FOR EACH ROW
WHEN (OLD.pkgver != NEW.pkgver OR OLD.pkgrel != NEW.pkgrel OR OLD.epoch != NEW.epoch)
EXECUTE PROCEDURE packages_on_update();
DROP TRIGGER IF EXISTS packages_delete ON packages;
CREATE TRIGGER packages_delete
AFTER DELETE ON packages
FOR EACH ROW
EXECUTE PROCEDURE packages_on_delete();

View File

@ -0,0 +1,30 @@
DROP TRIGGER IF EXISTS packages_insert;
CREATE TRIGGER packages_insert
AFTER INSERT ON packages
FOR EACH ROW
BEGIN
INSERT INTO packages_update
(action_flag, created, package_id, arch_id, repo_id, pkgname, pkgbase, new_pkgver, new_pkgrel, new_epoch)
VALUES (1, strftime('%Y-%m-%d %H:%M:%f', 'now'), NEW.id, NEW.arch_id, NEW.repo_id, NEW.pkgname, NEW.pkgbase, NEW.pkgver, NEW.pkgrel, NEW.epoch);
END;
DROP TRIGGER IF EXISTS packages_update;
CREATE TRIGGER packages_update
AFTER UPDATE ON packages
FOR EACH ROW
WHEN (OLD.pkgver != NEW.pkgver OR OLD.pkgrel != NEW.pkgrel OR OLD.epoch != NEW.epoch)
BEGIN
INSERT INTO packages_update
(action_flag, created, package_id, arch_id, repo_id, pkgname, pkgbase, old_pkgver, old_pkgrel, old_epoch, new_pkgver, new_pkgrel, new_epoch)
VALUES (2, strftime('%Y-%m-%d %H:%M:%f', 'now'), NEW.id, NEW.arch_id, NEW.repo_id, NEW.pkgname, NEW.pkgbase, OLD.pkgver, OLD.pkgrel, OLD.epoch, NEW.pkgver, NEW.pkgrel, NEW.epoch);
END;
DROP TRIGGER IF EXISTS packages_delete;
CREATE TRIGGER packages_delete
AFTER DELETE ON packages
FOR EACH ROW
BEGIN
INSERT INTO packages_update
(action_flag, created, arch_id, repo_id, pkgname, pkgbase, old_pkgver, old_pkgrel, old_epoch)
VALUES (3, strftime('%Y-%m-%d %H:%M:%f', 'now'), OLD.arch_id, OLD.repo_id, OLD.pkgname, OLD.pkgbase, OLD.pkgver, OLD.pkgrel, OLD.epoch);
END;