-
Notifications
You must be signed in to change notification settings - Fork 5
ENG-1311 Unify ConceptAccess and ContentAccess tables #712
New issue
Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.
By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.
Already on GitHub? Sign in to your account
Open
maparent
wants to merge
10
commits into
main
Choose a base branch
from
eng-1311-unify-conceptaccess-and-contentaccess-tables
base: main
Could not load branches
Branch not found: {{ refName }}
Loading
Could not load tags
Nothing to show
Loading
Are you sure you want to change the base?
Some commits from the old base branch may be removed from the timeline,
and old review comments may become outdated.
+339
−179
Open
Changes from all commits
Commits
Show all changes
10 commits
Select commit
Hold shift + click to select a range
832866d
eng-1311 use ContentAccess for ConceptAccess
maparent 4e8f0a4
Add triggers to delete ContentAccess when appropriate
maparent fbb64cf
coderabbit corrections
maparent a8efd59
update my_documents view
maparent bb955ed
correction
maparent e644500
corrections
maparent 6795b6e
nit: limit 1
maparent d3c1c76
Rename ContentAccess to ResourceAccess
maparent 33acc4e
Gentypes ordering
maparent 73d5057
also rename can_view_specific_content->resource
maparent File filter
Filter by extension
Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
Some comments aren't visible on the classic Files Changed page.
There are no files selected for viewing
This file contains hidden or bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
192 changes: 192 additions & 0 deletions
192
packages/database/supabase/migrations/20260117210851_unify_concept_content_access_tables.sql
This file contains hidden or bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
| Original file line number | Diff line number | Diff line change |
|---|---|---|
| @@ -0,0 +1,192 @@ | ||
| DROP TABLE public."ConceptAccess" CASCADE; | ||
maparent marked this conversation as resolved.
Show resolved
Hide resolved
|
||
|
|
||
| ALTER TABLE public."ContentAccess" RENAME TO "ResourceAccess"; | ||
| ALTER TABLE public."ResourceAccess" RENAME CONSTRAINT "ContentAccess_pkey" TO "ResourceAccess_pkey"; | ||
| ALTER TABLE public."ResourceAccess" RENAME CONSTRAINT "ContentAccess_account_uid_fkey" TO "ResourceAccess_account_uid_fkey"; | ||
|
|
||
| ALTER TABLE public."ResourceAccess" ADD COLUMN space_id BIGINT; | ||
| ALTER TABLE public."ResourceAccess" ADD COLUMN source_local_id CHARACTER VARYING; | ||
|
|
||
| COMMENT ON COLUMN public."ResourceAccess".space_id IS 'The space_id of the content item for which access is granted'; | ||
| COMMENT ON COLUMN public."ResourceAccess".source_local_id IS 'The source_local_id of the content item for which access is granted'; | ||
|
|
||
| UPDATE public."ResourceAccess" AS ca | ||
| SET space_id = ct.space_id, source_local_id = ct.source_local_id | ||
| FROM public."Content" AS ct WHERE ct.id = content_id; | ||
|
|
||
| ALTER TABLE public."ResourceAccess" DROP COLUMN content_id CASCADE; | ||
| -- cascades to Content policies, indices, primary key... | ||
|
|
||
| ALTER TABLE public."ResourceAccess" ALTER COLUMN space_id SET NOT NULL; | ||
| ALTER TABLE public."ResourceAccess" ALTER COLUMN source_local_id SET NOT NULL; | ||
|
|
||
| ALTER TABLE ONLY public."ResourceAccess" | ||
| ADD CONSTRAINT "ResourceAccess_pkey" PRIMARY KEY (account_uid, source_local_id, space_id); | ||
|
|
||
| CREATE INDEX resource_access_content_local_id_idx ON public."ResourceAccess" (source_local_id, space_id); | ||
|
|
||
| CREATE OR REPLACE FUNCTION public.can_view_specific_resource(space_id_ BIGINT, source_local_id_ VARCHAR) RETURNS BOOLEAN | ||
| STABLE SECURITY DEFINER | ||
| SET search_path = '' | ||
| LANGUAGE sql | ||
| AS $$ | ||
| SELECT EXISTS( | ||
| SELECT true FROM public."ResourceAccess" | ||
| JOIN public.my_user_accounts() ON (account_uid=my_user_accounts) | ||
| WHERE space_id=space_id_ | ||
| AND source_local_id = source_local_id_ | ||
| LIMIT 1); | ||
| $$; | ||
|
|
||
| CREATE OR REPLACE VIEW public.my_documents AS | ||
| SELECT | ||
| id, | ||
| space_id, | ||
| source_local_id, | ||
| url, | ||
| "created", | ||
| metadata, | ||
| last_modified, | ||
| author_id, | ||
| contents | ||
| FROM public."Document" WHERE space_id = any(public.my_space_ids()) | ||
| OR public.can_view_specific_resource(space_id, source_local_id); | ||
|
|
||
| CREATE OR REPLACE VIEW public.my_contents AS | ||
| SELECT | ||
| id, | ||
| document_id, | ||
| source_local_id, | ||
| variant, | ||
| author_id, | ||
| creator_id, | ||
| created, | ||
| text, | ||
| metadata, | ||
| scale, | ||
| space_id, | ||
| last_modified, | ||
| part_of_id | ||
| FROM public."Content" | ||
| WHERE ( | ||
| space_id = any(public.my_space_ids()) | ||
| OR public.can_view_specific_resource(space_id, source_local_id) | ||
| ); | ||
|
|
||
| DROP POLICY IF EXISTS document_policy ON public."Document"; | ||
| DROP POLICY IF EXISTS document_select_policy ON public."Document"; | ||
| CREATE POLICY document_select_policy ON public."Document" FOR SELECT USING (public.in_space(space_id) OR public.can_view_specific_resource(space_id, source_local_id)); | ||
| DROP POLICY IF EXISTS document_delete_policy ON public."Document"; | ||
| CREATE POLICY document_delete_policy ON public."Document" FOR DELETE USING (public.in_space(space_id)); | ||
| DROP POLICY IF EXISTS document_insert_policy ON public."Document"; | ||
| CREATE POLICY document_insert_policy ON public."Document" FOR INSERT WITH CHECK (public.in_space(space_id)); | ||
| DROP POLICY IF EXISTS document_update_policy ON public."Document"; | ||
| CREATE POLICY document_update_policy ON public."Document" FOR UPDATE USING (public.in_space(space_id)); | ||
|
|
||
| DROP POLICY IF EXISTS content_select_policy ON public."Content"; | ||
| CREATE POLICY content_select_policy ON public."Content" FOR SELECT USING (public.in_space(space_id) OR public.can_view_specific_resource(space_id, source_local_id)); | ||
|
|
||
| DROP POLICY IF EXISTS content_access_select_policy ON public."ResourceAccess"; | ||
| DROP POLICY IF EXISTS content_access_delete_policy ON public."ResourceAccess"; | ||
| DROP POLICY IF EXISTS content_access_insert_policy ON public."ResourceAccess"; | ||
| DROP POLICY IF EXISTS content_access_update_policy ON public."ResourceAccess"; | ||
|
|
||
| DROP POLICY IF EXISTS resource_access_select_policy ON public."ResourceAccess"; | ||
| CREATE POLICY resource_access_select_policy ON public."ResourceAccess" FOR SELECT USING (public.in_space(space_id) OR public.can_access_account(account_uid)); | ||
| DROP POLICY IF EXISTS resource_access_delete_policy ON public."ResourceAccess"; | ||
| CREATE POLICY resource_access_delete_policy ON public."ResourceAccess" FOR DELETE USING (public.editor_in_space(space_id) OR public.can_access_account(account_uid)); | ||
| DROP POLICY IF EXISTS resource_access_insert_policy ON public."ResourceAccess"; | ||
| CREATE POLICY resource_access_insert_policy ON public."ResourceAccess" FOR INSERT WITH CHECK (public.editor_in_space(space_id)); | ||
| DROP POLICY IF EXISTS resource_access_update_policy ON public."ResourceAccess"; | ||
| CREATE POLICY resource_access_update_policy ON public."ResourceAccess" FOR UPDATE USING (public.editor_in_space(space_id)); | ||
|
|
||
| DROP FUNCTION public.can_view_specific_content(BIGINT); | ||
|
|
||
| CREATE OR REPLACE VIEW public.my_concepts AS | ||
| SELECT | ||
| id, | ||
| epistemic_status, | ||
| name, | ||
| description, | ||
| author_id, | ||
| created, | ||
| last_modified, | ||
| space_id, | ||
| arity, | ||
| schema_id, | ||
| literal_content, | ||
| reference_content, | ||
| refs, | ||
| is_schema, | ||
| source_local_id | ||
| FROM public."Concept" | ||
| WHERE ( | ||
| space_id = any(public.my_space_ids()) | ||
| OR public.can_view_specific_resource(space_id, source_local_id) | ||
| ); | ||
|
|
||
|
|
||
| DROP POLICY IF EXISTS concept_select_policy ON public."Concept"; | ||
| CREATE POLICY concept_select_policy ON public."Concept" FOR SELECT USING (public.in_space(space_id) OR public.can_view_specific_resource(space_id, source_local_id)); | ||
|
|
||
| DROP FUNCTION public.can_view_specific_concept(BIGINT); | ||
|
|
||
| CREATE OR REPLACE FUNCTION public.is_last_local_reference(space_id_ BIGINT, source_local_id_ VARCHAR) RETURNS boolean | ||
| STABLE | ||
| SET search_path = '' | ||
| SECURITY DEFINER | ||
| LANGUAGE sql | ||
| AS $$ | ||
| SELECT NOT EXISTS (SELECT id FROM public."Content" WHERE space_id=space_id_ AND source_local_id=source_local_id_ LIMIT 1) | ||
| AND NOT EXISTS (SELECT id FROM public."Concept" WHERE space_id=space_id_ AND source_local_id=source_local_id_ LIMIT 1) | ||
| AND NOT EXISTS (SELECT id FROM public."Document" WHERE space_id=space_id_ AND source_local_id=source_local_id_ LIMIT 1); | ||
| $$; | ||
|
|
||
| CREATE OR REPLACE FUNCTION on_delete_local_reference() RETURNS TRIGGER | ||
| SET search_path = '' | ||
| SECURITY DEFINER | ||
| LANGUAGE plpgsql | ||
| AS $$ | ||
| BEGIN | ||
| IF public.is_last_local_reference(OLD.space_id, OLD.source_local_id) THEN | ||
| DELETE FROM public."ResourceAccess" WHERE space_id=OLD.space_id AND source_local_id=OLD.source_local_id; | ||
| END IF; | ||
| RETURN OLD; | ||
| END; | ||
| $$; | ||
|
|
||
| CREATE TRIGGER on_delete_content_trigger AFTER DELETE ON public."Content" FOR EACH ROW EXECUTE FUNCTION public.on_delete_local_reference(); | ||
| CREATE TRIGGER on_delete_concept_trigger AFTER DELETE ON public."Concept" FOR EACH ROW EXECUTE FUNCTION public.on_delete_local_reference(); | ||
| CREATE TRIGGER on_delete_document_trigger AFTER DELETE ON public."Document" FOR EACH ROW EXECUTE FUNCTION public.on_delete_local_reference(); | ||
|
|
||
| CREATE OR REPLACE FUNCTION on_update_local_reference() RETURNS TRIGGER | ||
| SET search_path = '' | ||
| SECURITY DEFINER | ||
| LANGUAGE plpgsql | ||
| AS $$ | ||
| BEGIN | ||
| IF (OLD.space_id IS DISTINCT FROM NEW.space_id OR | ||
| OLD.source_local_id IS DISTINCT FROM NEW.source_local_id) | ||
| AND public.is_last_local_reference(OLD.space_id, OLD.source_local_id) THEN | ||
| DELETE FROM public."ResourceAccess" WHERE space_id=OLD.space_id AND source_local_id=OLD.source_local_id; | ||
| END IF; | ||
| RETURN NEW; | ||
| END; | ||
| $$; | ||
|
|
||
| CREATE TRIGGER on_update_content_trigger AFTER UPDATE ON public."Content" FOR EACH ROW EXECUTE FUNCTION public.on_update_local_reference(); | ||
| CREATE TRIGGER on_update_concept_trigger AFTER UPDATE ON public."Concept" FOR EACH ROW EXECUTE FUNCTION public.on_update_local_reference(); | ||
| CREATE TRIGGER on_update_document_trigger AFTER UPDATE ON public."Document" FOR EACH ROW EXECUTE FUNCTION public.on_update_local_reference(); | ||
|
|
||
| CREATE OR REPLACE FUNCTION public.on_delete_space_revoke_local_access() RETURNS TRIGGER | ||
| SET search_path = '' | ||
| SECURITY DEFINER | ||
| LANGUAGE plpgsql | ||
| AS $$ | ||
| BEGIN | ||
| DELETE FROM public."ResourceAccess" WHERE space_id=OLD.id; | ||
| RETURN OLD; | ||
| END; | ||
| $$; | ||
|
|
||
| CREATE TRIGGER on_delete_space_revoke_access_trigger AFTER DELETE ON public."Space" FOR EACH ROW EXECUTE FUNCTION public.on_delete_space_revoke_local_access(); | ||
Oops, something went wrong.
Add this suggestion to a batch that can be applied as a single commit.
This suggestion is invalid because no changes were made to the code.
Suggestions cannot be applied while the pull request is closed.
Suggestions cannot be applied while viewing a subset of changes.
Only one suggestion per line can be applied in a batch.
Add this suggestion to a batch that can be applied as a single commit.
Applying suggestions on deleted lines is not supported.
You must change the existing code in this line in order to create a valid suggestion.
Outdated suggestions cannot be applied.
This suggestion has been applied or marked resolved.
Suggestions cannot be applied from pending reviews.
Suggestions cannot be applied on multi-line comments.
Suggestions cannot be applied while the pull request is queued to merge.
Suggestion cannot be applied right now. Please check back later.
Uh oh!
There was an error while loading. Please reload this page.