replace the slow postgres trigger function for updating label names

This commit is contained in:
Hongbo Wu
2024-01-11 10:21:36 +08:00
parent f81ad17fb1
commit 1d4d373508
2 changed files with 60 additions and 0 deletions

View File

@ -0,0 +1,30 @@
-- Type: DO
-- Name: create_label_names_update_trigger
-- Description: Create label_names_update trigger in library_item table
BEGIN;
CREATE OR REPLACE FUNCTION update_label_names()
RETURNS TRIGGER AS $$
BEGIN
UPDATE omnivore.library_item
SET label_names = array_replace(label_names, OLD.name, NEW.name)
WHERE user_id = OLD.user_id AND OLD.name = ANY(label_names);
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
-- triggers when label name is updated
CREATE TRIGGER label_names_update
AFTER UPDATE ON omnivore.labels
FOR EACH ROW
WHEN (OLD.name <> NEW.name)
EXECUTE FUNCTION update_label_names();
-- remove old trigger which is too slow
DROP TRIGGER IF EXISTS entity_labels_update ON omnivore.labels;
DROP FUNCTION IF EXISTS omnivore.update_entity_labels();
COMMIT;

View File

@ -0,0 +1,30 @@
-- Type: UNDO
-- Name: create_label_names_update_trigger
-- Description: Create label_names_update trigger in library_item table
BEGIN;
CREATE OR REPLACE FUNCTION update_entity_labels()
RETURNS trigger AS $$
BEGIN
-- update entity_labels table to trigger update on library_item table
UPDATE omnivore.entity_labels
SET label_id = NEW.id
WHERE label_id = OLD.id;
return NEW;
END;
$$ LANGUAGE plpgsql;
-- triggers when label name is updated
CREATE TRIGGER entity_labels_update
AFTER UPDATE ON omnivore.labels
FOR EACH ROW
WHEN (OLD.name <> NEW.name)
EXECUTE FUNCTION update_entity_labels();
DROP TRIGGER IF EXISTS label_names_update ON omnivore.labels;
DROP FUNCTION IF EXISTS omnivore.update_label_names();
COMMIT;