Skip to content

Commit

Permalink
feat: add categories for software
Browse files Browse the repository at this point in the history
  • Loading branch information
fembau committed Sep 25, 2023
1 parent 7aa0451 commit de4201a
Show file tree
Hide file tree
Showing 24 changed files with 932 additions and 78 deletions.
213 changes: 213 additions & 0 deletions database/007-create-keyword-and-category.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,213 @@
-- SPDX-FileCopyrightText: 2022 Ewan Cahen (Netherlands eScience Center) <[email protected]>
-- SPDX-FileCopyrightText: 2022 Netherlands eScience Center
-- SPDX-FileCopyrightText: 2023 Felix Mühlbauer (GFZ) <[email protected]>
-- SPDX-FileCopyrightText: 2023 Helmholtz Centre Potsdam - GFZ German Research Centre for Geosciences
--
-- SPDX-License-Identifier: Apache-2.0

--------------
-- Keywords --
--------------

CREATE TABLE keyword (
id UUID DEFAULT gen_random_uuid() PRIMARY KEY,
value CITEXT UNIQUE CHECK (value ~ '^\S+( \S+)*$')
);

CREATE FUNCTION sanitise_insert_keyword() RETURNS TRIGGER LANGUAGE plpgsql AS
$$
BEGIN
NEW.id = gen_random_uuid();
return NEW;
END
$$;

CREATE TRIGGER sanitise_insert_keyword BEFORE INSERT ON keyword FOR EACH ROW EXECUTE PROCEDURE sanitise_insert_keyword();


CREATE FUNCTION sanitise_update_keyword() RETURNS TRIGGER LANGUAGE plpgsql AS
$$
BEGIN
NEW.id = OLD.id;
return NEW;
END
$$;

CREATE TRIGGER sanitise_update_keyword BEFORE UPDATE ON keyword FOR EACH ROW EXECUTE PROCEDURE sanitise_update_keyword();


CREATE TABLE keyword_for_software (
software UUID references software (id),
keyword UUID references keyword (id),
PRIMARY KEY (software, keyword)
);

CREATE TABLE keyword_for_project (
project UUID references project (id),
keyword UUID references keyword (id),
PRIMARY KEY (project, keyword)
);

-- ADD basic keywords from topics and tags
INSERT into keyword (value)
VALUES
('Big data'),
('GPU'),
('High performance computing'),
('Image processing'),
('Inter-operability & linked data'),
('Machine learning'),
('Multi-scale & multi model simulations'),
('Optimized data handling'),
('Real time data analysis'),
('Text analysis & natural language processing'),
('Visualization'),
('Workflow technologies');

----------------
-- Categories --
----------------

CREATE TABLE category (
id UUID PRIMARY KEY,
parent UUID REFERENCES category DEFAULT NULL,
short_name VARCHAR NOT NULL,
name VARCHAR NOT NULL,
icon VARCHAR DEFAULT NULL,

CONSTRAINT unique_short_name UNIQUE NULLS NOT DISTINCT (parent, short_name),
CONSTRAINT unique_name UNIQUE NULLS NOT DISTINCT (parent, name)
);

CREATE TABLE category_for_software (
software_id UUID references software (id),
category_id UUID references category (id),
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
$$
WITH RECURSIVE cat_path AS (
SELECT *, 1 AS r_index
FROM category WHERE id = category_id
UNION ALL
SELECT category.*, cat_path.r_index+1
FROM category
JOIN cat_path
ON category.id = cat_path.parent
)
-- 1. How can we reverse the output rows without injecting a new column (r_index)?
-- 2. How a table row "type" could be used here Now we have to list all columns of `category` explicitely
-- I want to have something like `* without 'r_index'` to be independant from modifications of `category`
-- 3. Maybe this could be improved by using SEARCH keyword.
SELECT id, parent, short_name, name, icon
FROM cat_path
ORDER BY r_index DESC;
$$;

-- returns a list of `category` entries traversing from the tree root to entry with `category_id`
CREATE FUNCTION category_path_expanded(category_id UUID)
RETURNS JSON
LANGUAGE SQL STABLE AS
$$
SELECT json_agg(row_to_json) AS path FROM (SELECT row_to_json(category_path(category_id))) AS cats;
$$;


CREATE FUNCTION category_paths_by_software_expanded(software_id UUID)
RETURNS JSON
LANGUAGE SQL STABLE AS
$$
WITH
cat_ids AS
(SELECT category_id FROM category_for_software AS c4s WHERE c4s.software_id = category_paths_by_software_expanded.software_id),
paths AS
(SELECT category_path_expanded(category_id) AS path FROM cat_ids)
SELECT
CASE WHEN EXISTS(SELECT 1 FROM cat_ids) THEN (SELECT json_agg(path) FROM paths)
ELSE '[]'::json
END AS result
$$;


CREATE FUNCTION available_categories_expanded()
RETURNS JSON
LANGUAGE SQL STABLE AS
$$
WITH
cat_ids AS
(SELECT id AS category_id FROM category AS node WHERE NOT EXISTS (SELECT 1 FROM category AS sub WHERE node.id = sub.parent)),
paths AS
(SELECT category_path_expanded(category_id) AS path FROM cat_ids)
SELECT
CASE WHEN EXISTS(SELECT 1 FROM cat_ids) THEN (SELECT json_agg(path) AS result FROM paths)
ELSE '[]'::json
END
$$
59 changes: 0 additions & 59 deletions database/007-create-keyword.sql

This file was deleted.

41 changes: 40 additions & 1 deletion database/020-row-level-security.sql
Original file line number Diff line number Diff line change
Expand Up @@ -2,9 +2,10 @@
-- SPDX-FileCopyrightText: 2021 - 2023 Netherlands eScience Center
-- SPDX-FileCopyrightText: 2022 - 2023 Dusan Mijatovic (dv4all)
-- SPDX-FileCopyrightText: 2022 - 2023 dv4all
-- SPDX-FileCopyrightText: 2022 - 2023 Helmholtz Centre Potsdam - GFZ German Research Centre for Geosciences
-- SPDX-FileCopyrightText: 2022 Christian Meeßen (GFZ) <[email protected]>
-- SPDX-FileCopyrightText: 2022 Helmholtz Centre Potsdam - GFZ German Research Centre for Geosciences
-- SPDX-FileCopyrightText: 2023 Dusan Mijatovic (Netherlands eScience Center)
-- SPDX-FileCopyrightText: 2023 Felix Mühlbauer (GFZ) <[email protected]>
--
-- SPDX-License-Identifier: Apache-2.0

Expand Down Expand Up @@ -276,6 +277,44 @@ CREATE POLICY admin_all_rights ON testimonial TO rsd_admin
USING (TRUE)
WITH CHECK (TRUE);


-- categories

ALTER TABLE category ENABLE ROW LEVEL SECURITY;

-- allow everybody to read
CREATE POLICY anyone_can_read ON category
FOR SELECT
TO rsd_web_anon, rsd_user
USING (TRUE);

-- allow admins to have full read/write access
CREATE POLICY admin_all_rights ON category
TO rsd_admin
USING (TRUE);


-- categories for software

ALTER TABLE category_for_software ENABLE ROW LEVEL SECURITY;

-- allow everybody to read metadata of published software
CREATE POLICY anyone_can_read ON category_for_software
FOR SELECT
TO rsd_web_anon, rsd_user
USING (EXISTS(SELECT 1 FROM software WHERE id = software_id));

-- allow software maintainers to have read/write access to their software
CREATE POLICY maintainer_all_rights ON category_for_software
TO rsd_user
USING (software_id IN (SELECT * FROM software_of_current_maintainer()));

-- allow admins to have full read/write access
CREATE POLICY admin_all_rights ON category_for_software
TO rsd_admin
USING (TRUE);


-- keywords
ALTER TABLE keyword ENABLE ROW LEVEL SECURITY;

Expand Down
Loading

0 comments on commit de4201a

Please sign in to comment.