From 064079b57e2fcb5086846f861c3a0649b297249d Mon Sep 17 00:00:00 2001 From: lorinjameson Date: Fri, 2 Aug 2024 16:07:45 -0400 Subject: [PATCH 1/2] Alt get_available_layers_rpc --- .../get_available_layers(alternative).sql | 55 +++++++++++++++++++ 1 file changed, 55 insertions(+) create mode 100644 SQL Scripts/functions/get_available_layers(alternative).sql diff --git a/SQL Scripts/functions/get_available_layers(alternative).sql b/SQL Scripts/functions/get_available_layers(alternative).sql new file mode 100644 index 0000000..1cae119 --- /dev/null +++ b/SQL Scripts/functions/get_available_layers(alternative).sql @@ -0,0 +1,55 @@ +CREATE +OR REPLACE FUNCTION get_availabale_layers_rpc ( + _project_id uuid +) RETURNS TABLE ( + document_id uuid, + layer_id uuid, + context_id uuid, + is_active BOOLEAN, + context_name VARCHAR +) +AS $body$ +DECLARE + _context_name VARCHAR; + _document_id uuid; + _contexts_row public.contexts % rowtype; + _layer_context_row public.layer_contexts % rowtype; + _layer_row public.layers % rowtype; +BEGIN + + -- Check project policy that contexts can be selected by this user + IF NOT (check_action_policy_organization(auth.uid(), 'contexts', 'SELECT') + OR check_action_policy_project(auth.uid(), 'contexts', 'SELECT', _project_id)) + THEN + RETURN NEXT; + END IF; + + -- Find all documents in the current context + FOR _contexts_row IN SELECT * FROM public.contexts c + WHERE c.project_id = _project_id + LOOP + RAISE LOG 'Found Context %', _contexts_row.id; + FOR _layer_context_row IN SELECT * FROM public.layer_contexts lcx + WHERE lcx.context_id = _contexts_row.id AND lcx.is_archived IS NOT TRUE + LOOP + RAISE LOG 'Found Layer Context %, Layer ID % ', _layer_context_row.id, _layer_context_row.layer_id; + FOR _document_id IN SELECT cd.document_id + FROM public.context_documents cd WHERE cd.context_id = _layer_context_row.context_id AND cd.is_archived IS NOT TRUE + LOOP + RAISE LOG 'Found Document %', _document_id; + FOR _layer_row IN SELECT * FROM public.layers l + WHERE l.id = _layer_context_row.layer_id AND l.document_id = _document_id AND l.is_archived IS NOT TRUE + LOOP + document_id := _document_id; + context_id := _contexts_row.id; + is_active := _layer_context_row.is_active_layer; + layer_id := _layer_row.id; + context_name := _contexts_row.name; + RAISE LOG 'Found Available Document %', _document_id; + RETURN NEXT; + END LOOP; + END LOOP; + END LOOP; + END LOOP; +END +$body$ LANGUAGE plpgsql SECURITY DEFINER; \ No newline at end of file From 540f1ddefd8d832bba4e8491e495e180c81bffd4 Mon Sep 17 00:00:00 2001 From: dleadbetter Date: Mon, 21 Oct 2024 10:48:29 -0400 Subject: [PATCH 2/2] #86 - Adding "document_view_right" column to "projects" --- SQL Scripts/functions/create_project_rpc.sql | 13 ++++---- SQL Scripts/tables/projects.sql | 9 ++++-- ...05_add_document_view_right_to_projects.sql | 32 +++++++++++++++++++ 3 files changed, 46 insertions(+), 8 deletions(-) create mode 100644 supabase/migrations/20241018111105_add_document_view_right_to_projects.sql diff --git a/SQL Scripts/functions/create_project_rpc.sql b/SQL Scripts/functions/create_project_rpc.sql index ae813ac..a10863f 100644 --- a/SQL Scripts/functions/create_project_rpc.sql +++ b/SQL Scripts/functions/create_project_rpc.sql @@ -1,9 +1,10 @@ CREATE -OR REPLACE FUNCTION create_project_rpc ( + OR REPLACE FUNCTION create_project_rpc ( _name VARCHAR, _description VARCHAR, _is_open_join BOOLEAN, - _is_open_edit BOOLEAN + _is_open_edit BOOLEAN, + _document_view_right DOCUMENT_VIEW_TYPE ) RETURNS SETOF public.projects AS $body$ DECLARE _project_id uuid := gen_random_uuid(); -- The id of the new project @@ -12,16 +13,16 @@ DECLARE BEGIN IF NOT check_action_policy_organization(auth.uid(), 'projects', 'INSERT') THEN RETURN; - END IF; + END IF; - INSERT INTO public.projects (id, created_by, created_at, name, description, is_open_join, is_open_edit) VALUES (_project_id, auth.uid(), NOW(), _name, _description, _is_open_join, _is_open_edit); + INSERT INTO public.projects (id, created_by, created_at, name, description, is_open_join, is_open_edit, document_view_right) VALUES (_project_id, auth.uid(), NOW(), _name, _description, _is_open_join, _is_open_edit, _document_view_right); INSERT INTO public.contexts (id, created_by, created_at, project_id, is_project_default) VALUES (_context_id, auth.uid(), NOW(), _project_id, TRUE); SELECT (id) INTO _default_context_definition_id FROM public.tag_definitions t WHERE t.scope = 'system' AND t.name = 'DEFAULT_CONTEXT'; - INSERT INTO public.tags (created_by, created_at, tag_definition_id, target_id) VALUES (auth.uid(), NOW(), _default_context_definition_id, _context_id); - + INSERT INTO public.tags (created_by, created_at, tag_definition_id, target_id) VALUES (auth.uid(), NOW(), _default_context_definition_id, _context_id); + RETURN QUERY SELECT * FROM public.projects WHERE id = _project_id; END $body$ LANGUAGE plpgsql SECURITY DEFINER; \ No newline at end of file diff --git a/SQL Scripts/tables/projects.sql b/SQL Scripts/tables/projects.sql index 5a0e835..bcb385f 100644 --- a/SQL Scripts/tables/projects.sql +++ b/SQL Scripts/tables/projects.sql @@ -10,7 +10,8 @@ CREATE TABLE description VARCHAR, is_open_join BOOLEAN DEFAULT FALSE, is_open_edit BOOLEAN DEFAULT FALSE, - is_locked BOOLEAN DEFAULT FALSE + is_locked BOOLEAN DEFAULT FALSE, + document_view_right DOCUMENT_VIEW_TYPE DEFAULT 'closed' ); -- Changes 04/21/23 -- @@ -38,4 +39,8 @@ ADD COLUMN is_open_edit BOOLEAN DEFAULT FALSE; -- Changes 9/20/24 ALTER TABLE public.projects -ADD COLUMN is_locked BOOLEAN DEFAULT FALSE; \ No newline at end of file +ADD COLUMN is_locked BOOLEAN DEFAULT FALSE; + +-- Changes 10/18/24 +ALTER TABLE public.projects +ADD COLUMN document_view_right DOCUMENT_VIEW_TYPE DEFAULT 'closed'; \ No newline at end of file diff --git a/supabase/migrations/20241018111105_add_document_view_right_to_projects.sql b/supabase/migrations/20241018111105_add_document_view_right_to_projects.sql new file mode 100644 index 0000000..9a06a66 --- /dev/null +++ b/supabase/migrations/20241018111105_add_document_view_right_to_projects.sql @@ -0,0 +1,32 @@ +create type "public".document_view_type as enum ('closed', 'annotations', 'notes'); + +alter table "public"."projects" add column "document_view_right" document_view_type default 'closed'; + +CREATE + OR REPLACE FUNCTION create_project_rpc ( + _name VARCHAR, + _description VARCHAR, + _is_open_join BOOLEAN, + _is_open_edit BOOLEAN, + _document_view_right DOCUMENT_VIEW_TYPE +) RETURNS SETOF public.projects AS $body$ +DECLARE + _project_id uuid := gen_random_uuid(); -- The id of the new project + _context_id uuid := gen_random_uuid(); -- The id of the default context + _default_context_definition_id uuid; +BEGIN + IF NOT check_action_policy_organization(auth.uid(), 'projects', 'INSERT') THEN + RETURN; + END IF; + + INSERT INTO public.projects (id, created_by, created_at, name, description, is_open_join, is_open_edit, document_view_right) VALUES (_project_id, auth.uid(), NOW(), _name, _description, _is_open_join, _is_open_edit, _document_view_right); + + INSERT INTO public.contexts (id, created_by, created_at, project_id, is_project_default) VALUES (_context_id, auth.uid(), NOW(), _project_id, TRUE); + + SELECT (id) INTO _default_context_definition_id FROM public.tag_definitions t WHERE t.scope = 'system' AND t.name = 'DEFAULT_CONTEXT'; + + INSERT INTO public.tags (created_by, created_at, tag_definition_id, target_id) VALUES (auth.uid(), NOW(), _default_context_definition_id, _context_id); + + RETURN QUERY SELECT * FROM public.projects WHERE id = _project_id; +END +$body$ LANGUAGE plpgsql SECURITY DEFINER; \ No newline at end of file