Add trigger to update label positions before insert and delete

This commit is contained in:
Hongbo Wu
2022-07-28 16:16:36 +08:00
parent 31d8f72840
commit bac33e887c
2 changed files with 24 additions and 1 deletions

View File

@ -20,6 +20,25 @@ WITH positions AS (
WHERE
omnivore.labels.id = positions.id;
ALTER TABLE omnivore.labels ADD constraint labels_position_user_id_unique UNIQUE(user_id, position);
CREATE OR REPLACE FUNCTION update_label_position()
RETURNS TRIGGER AS $$
DECLARE
new_position INTEGER;
BEGIN
IF (TG_OP = 'DELETE') THEN
UPDATE omnivore.labels SET position = position - 1 WHERE user_id = OLD.user_id AND position > OLD.position;
RETURN OLD;
ELSIF (TG_OP = 'INSERT') THEN
SELECT MAX(position) + 1 INTO new_position FROM omnivore.labels WHERE user_id = NEW.user_id;
NEW.position = new_position;
RETURN NEW;
END IF;
END;
$$ LANGUAGE 'plpgsql';
CREATE TRIGGER update_label_position
BEFORE INSERT OR DELETE ON omnivore.labels
FOR EACH ROW
EXECUTE FUNCTION update_label_position();
COMMIT;

View File

@ -4,6 +4,10 @@
BEGIN;
DROP TRIGGER IF EXISTS update_label_position ON omnivore.labels;
DROP FUNCTION IF EXISTS update_label_position;
ALTER TABLE omnivore.labels DROP COLUMN IF EXISTS position;
COMMIT;