diff --git a/TODOs.md b/TODOs.md index d3535ddaa..a71ecb0fb 100644 --- a/TODOs.md +++ b/TODOs.md @@ -5,3 +5,16 @@ TODOs for category feature - add backend test? how? - how should be abbreviate some of these long category names? - the API calling functions have a lot of copy&paste code. Let's create some generic helper functions for API calls +- eval use of WITH RECURSIVE..SEARCH for category_path() + +DB tests +======== + +- unique category short_name, name for top level and for sub-level categories +- prevent cycles in categories. single + multi statements +- update category id + +FE tests +======== + +- ? \ No newline at end of file diff --git a/database/007-create-keyword-and-category.sql b/database/007-create-keyword-and-category.sql index df045a40f..80208b39f 100644 --- a/database/007-create-keyword-and-category.sql +++ b/database/007-create-keyword-and-category.sql @@ -70,7 +70,7 @@ VALUES ---------------- CREATE TABLE category ( - id UUID DEFAULT gen_random_uuid() PRIMARY KEY, + id UUID PRIMARY KEY, parent UUID REFERENCES category DEFAULT NULL, short_name VARCHAR NOT NULL, name VARCHAR NOT NULL, @@ -85,6 +85,71 @@ CREATE TABLE category_for_software ( PRIMARY KEY (software_id, category_id) ); + +-- sanitize categories + +CREATE FUNCTION sanitise_insert_category() +RETURNS TRIGGER +LANGUAGE plpgsql +SECURITY DEFINER AS +$$ +BEGIN + IF NEW.id IS NOT NULL THEN + RAISE EXCEPTION USING MESSAGE = 'The category id is generated automatically and may not be set.'; + END IF; + NEW.id = gen_random_uuid(); + RETURN NEW; +END +$$; + +CREATE TRIGGER sanitise_insert_category + BEFORE INSERT ON category + FOR EACH ROW EXECUTE PROCEDURE sanitise_insert_category(); + + +CREATE FUNCTION sanitise_update_category() +RETURNS TRIGGER +LANGUAGE plpgsql +SECURITY DEFINER AS +$$ +BEGIN + IF NEW.id != OLD.id THEN + RAISE EXCEPTION USING MESSAGE = 'The category id may not be changed.'; + END IF; + RETURN NEW; +END +$$; + +CREATE TRIGGER sanitise_update_category + BEFORE UPDATE ON category + FOR EACH ROW EXECUTE PROCEDURE sanitise_update_category(); + + +CREATE FUNCTION check_cycle_categories() +RETURNS TRIGGER STABLE +LANGUAGE plpgsql +SECURITY DEFINER AS +$$ + DECLARE first_id UUID = NEW.id; + DECLARE current_id UUID = NEW.parent; +BEGIN + WHILE current_id IS NOT NULL LOOP + IF current_id = first_id THEN + RAISE EXCEPTION USING MESSAGE = 'Cycle detected for category with id ' || NEW.id; + END IF; + SELECT parent FROM category WHERE id = current_id INTO current_id; + END LOOP; + RETURN NEW; +END +$$; + +CREATE TRIGGER zzz_check_cycle_categories -- triggers are executed in alphabetical order + AFTER INSERT OR UPDATE ON category + FOR EACH ROW EXECUTE PROCEDURE check_cycle_categories(); + + +-- helper functions + CREATE FUNCTION category_path(category_id UUID) RETURNS TABLE (like category) LANGUAGE SQL STABLE AS diff --git a/database/999-add-hgf-categories.sql b/database/999-add-hgf-categories.sql index 68c155d67..2bfc59413 100644 --- a/database/999-add-hgf-categories.sql +++ b/database/999-add-hgf-categories.sql @@ -13,7 +13,7 @@ DECLARE parent_id uuid; DECLARE category varchar[]; BEGIN INSERT INTO category(short_name, name) VALUES (parent_short_name, parent_name) - RETURNING id INTO parent_id; + RETURNING id INTO parent_id; FOREACH category SLICE 1 IN ARRAY sub_categories LOOP INSERT INTO category(parent, short_name, name) VALUES (parent_id, category[1], category[2]); END LOOP;