diff --git a/packages/database/src/dbTypes.ts b/packages/database/src/dbTypes.ts index 8eac14f69..af239752b 100644 --- a/packages/database/src/dbTypes.ts +++ b/packages/database/src/dbTypes.ts @@ -226,36 +226,6 @@ export type Database = { }, ] } - ConceptAccess: { - Row: { - account_uid: string - concept_id: number - } - Insert: { - account_uid: string - concept_id: number - } - Update: { - account_uid?: string - concept_id?: number - } - Relationships: [ - { - foreignKeyName: "ConceptAccess_concept_id_fkey" - columns: ["concept_id"] - isOneToOne: false - referencedRelation: "Concept" - referencedColumns: ["id"] - }, - { - foreignKeyName: "ConceptAccess_concept_id_fkey" - columns: ["concept_id"] - isOneToOne: false - referencedRelation: "my_concepts" - referencedColumns: ["id"] - }, - ] - } Content: { Row: { author_id: number | null @@ -433,43 +403,6 @@ export type Database = { }, ] } - ContentAccess: { - Row: { - account_uid: string - content_id: number - } - Insert: { - account_uid: string - content_id: number - } - Update: { - account_uid?: string - content_id?: number - } - Relationships: [ - { - foreignKeyName: "ContentAccess_content_id_fkey" - columns: ["content_id"] - isOneToOne: false - referencedRelation: "Content" - referencedColumns: ["id"] - }, - { - foreignKeyName: "ContentAccess_content_id_fkey" - columns: ["content_id"] - isOneToOne: false - referencedRelation: "my_contents" - referencedColumns: ["id"] - }, - { - foreignKeyName: "ContentAccess_content_id_fkey" - columns: ["content_id"] - isOneToOne: false - referencedRelation: "my_contents_with_embedding_openai_text_embedding_3_small_1536" - referencedColumns: ["id"] - }, - ] - } ContentEmbedding_openai_text_embedding_3_small_1536: { Row: { model: Database["public"]["Enums"]["EmbeddingName"] @@ -676,6 +609,24 @@ export type Database = { } Relationships: [] } + ResourceAccess: { + Row: { + account_uid: string + source_local_id: string + space_id: number + } + Insert: { + account_uid: string + source_local_id: string + space_id: number + } + Update: { + account_uid?: string + source_local_id?: string + space_id?: number + } + Relationships: [] + } Space: { Row: { id: number @@ -1346,8 +1297,10 @@ export type Database = { } } can_access_account: { Args: { account_uid: string }; Returns: boolean } - can_view_specific_concept: { Args: { id: number }; Returns: boolean } - can_view_specific_content: { Args: { id: number }; Returns: boolean } + can_view_specific_resource: { + Args: { source_local_id_: string; space_id_: number } + Returns: boolean + } compute_arity_local: { Args: { lit_content: Json; schema_id: number } Returns: number @@ -1524,6 +1477,10 @@ export type Database = { } } is_group_admin: { Args: { group_id_: string }; Returns: boolean } + is_last_local_reference: { + Args: { source_local_id_: string; space_id_: number } + Returns: boolean + } is_my_account: { Args: { account_id: number }; Returns: boolean } match_content_embeddings: { Args: { @@ -1933,4 +1890,3 @@ export const Constants = { }, }, } as const - diff --git a/packages/database/supabase/migrations/20260117210851_unify_concept_content_access_tables.sql b/packages/database/supabase/migrations/20260117210851_unify_concept_content_access_tables.sql new file mode 100644 index 000000000..7721d13a8 --- /dev/null +++ b/packages/database/supabase/migrations/20260117210851_unify_concept_content_access_tables.sql @@ -0,0 +1,192 @@ +DROP TABLE public."ConceptAccess" CASCADE; + +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(); diff --git a/packages/database/supabase/schemas/concept.sql b/packages/database/supabase/schemas/concept.sql index 3af197e7c..b9a4eae74 100644 --- a/packages/database/supabase/schemas/concept.sql +++ b/packages/database/supabase/schemas/concept.sql @@ -109,52 +109,6 @@ REVOKE ALL ON TABLE public."Concept" FROM anon; GRANT ALL ON TABLE public."Concept" TO authenticated; GRANT ALL ON TABLE public."Concept" TO service_role; -CREATE TABLE IF NOT EXISTS public."ConceptAccess" ( - account_uid UUID NOT NULL, - concept_id bigint NOT NULL -); - -ALTER TABLE ONLY public."ConceptAccess" -ADD CONSTRAINT "ConceptAccess_pkey" PRIMARY KEY (account_uid, concept_id); - -ALTER TABLE public."ConceptAccess" OWNER TO "postgres"; - -COMMENT ON TABLE public."ConceptAccess" IS 'An access control entry for a concept'; - -COMMENT ON COLUMN public."ConceptAccess".concept_id IS 'The concept item for which access is granted'; - -COMMENT ON COLUMN public."ConceptAccess".account_uid IS 'The identity of the user account'; - -ALTER TABLE ONLY public."ConceptAccess" -ADD CONSTRAINT "ConceptAccess_account_uid_fkey" FOREIGN KEY ( - account_uid -) REFERENCES auth.users (id) ON UPDATE CASCADE ON DELETE CASCADE; - -CREATE INDEX concept_access_concept_id_idx ON public."ConceptAccess" (concept_id); - -ALTER TABLE ONLY public."ConceptAccess" -ADD CONSTRAINT "ConceptAccess_concept_id_fkey" FOREIGN KEY ( - concept_id -) REFERENCES public."Concept" ( - id -) ON UPDATE CASCADE ON DELETE CASCADE; - -GRANT ALL ON TABLE public."ConceptAccess" TO authenticated; -GRANT ALL ON TABLE public."ConceptAccess" TO service_role; -REVOKE ALL ON TABLE public."ConceptAccess" FROM anon; - -CREATE OR REPLACE FUNCTION public.can_view_specific_concept(id BIGINT) RETURNS BOOLEAN -STABLE SECURITY DEFINER -SET search_path = '' -LANGUAGE sql -AS $$ - SELECT EXISTS( - SELECT true FROM public."ConceptAccess" - JOIN public.my_user_accounts() ON (account_uid=my_user_accounts) - WHERE concept_id=id - LIMIT 1); -$$; - CREATE OR REPLACE VIEW public.my_concepts AS SELECT id, @@ -175,7 +129,7 @@ SELECT FROM public."Concept" WHERE ( space_id = any(public.my_space_ids()) - OR public.can_view_specific_concept(id) + OR public.can_view_specific_resource(space_id, source_local_id) ); -- following https://docs.postgrest.org/en/v13/references/api/resource_embedding.html#recursive-relationships @@ -454,7 +408,7 @@ ALTER TABLE public."Concept" ENABLE ROW LEVEL SECURITY; DROP POLICY IF EXISTS concept_policy ON public."Concept"; 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_concept(id)); +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 POLICY IF EXISTS concept_delete_policy ON public."Concept"; CREATE POLICY concept_delete_policy ON public."Concept" FOR DELETE USING (public.in_space(space_id)); DROP POLICY IF EXISTS concept_insert_policy ON public."Concept"; @@ -462,14 +416,66 @@ CREATE POLICY concept_insert_policy ON public."Concept" FOR INSERT WITH CHECK (p DROP POLICY IF EXISTS concept_update_policy ON public."Concept"; CREATE POLICY concept_update_policy ON public."Concept" FOR UPDATE USING (public.in_space(space_id)); -ALTER TABLE public."ConceptAccess" ENABLE ROW LEVEL SECURITY; - -DROP POLICY IF EXISTS concept_access_policy ON public."ConceptAccess"; -DROP POLICY IF EXISTS concept_access_select_policy ON public."ConceptAccess"; -CREATE POLICY concept_access_select_policy ON public."ConceptAccess" FOR SELECT USING (public.concept_in_space(concept_id) OR public.can_access_account(account_uid)); -DROP POLICY IF EXISTS concept_access_delete_policy ON public."ConceptAccess"; -CREATE POLICY concept_access_delete_policy ON public."ConceptAccess" FOR DELETE USING (public.concept_in_editable_space(concept_id) OR public.can_access_account(account_uid)); -DROP POLICY IF EXISTS concept_access_insert_policy ON public."ConceptAccess"; -CREATE POLICY concept_access_insert_policy ON public."ConceptAccess" FOR INSERT WITH CHECK (public.concept_in_editable_space(concept_id)); -DROP POLICY IF EXISTS concept_access_update_policy ON public."ConceptAccess"; -CREATE POLICY concept_access_update_policy ON public."ConceptAccess" FOR UPDATE USING (public.concept_in_editable_space(concept_id)); +-- since ResourceAccess is used for both Content and Concepts, +-- we cannot count on the usual foreign key delete cascades. +-- Implementing with triggers + +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(); diff --git a/packages/database/supabase/schemas/content.sql b/packages/database/supabase/schemas/content.sql index 57b5cf979..51f45cca5 100644 --- a/packages/database/supabase/schemas/content.sql +++ b/packages/database/supabase/schemas/content.sql @@ -70,19 +70,6 @@ COMMENT ON COLUMN public."Document".author_id IS 'The author of content'; COMMENT ON COLUMN public."Document".contents IS 'A large object OID for the downloaded raw content'; --- explicit fields require more maintenance, but respects declared table order. -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()); CREATE TABLE IF NOT EXISTS public."Content" ( id bigint DEFAULT nextval( @@ -166,39 +153,36 @@ COMMENT ON COLUMN public."Content".last_modified IS 'The last time the content w COMMENT ON COLUMN public."Content".part_of_id IS 'This content is part of a larger content unit'; -CREATE TABLE IF NOT EXISTS public."ContentAccess" ( +CREATE TABLE IF NOT EXISTS public."ResourceAccess" ( account_uid UUID NOT NULL, - content_id bigint NOT NULL + space_id bigint NOT NULL, + source_local_id CHARACTER VARYING NOT NULL ); -ALTER TABLE ONLY public."ContentAccess" -ADD CONSTRAINT "ContentAccess_pkey" PRIMARY KEY (account_uid, content_id); +ALTER TABLE ONLY public."ResourceAccess" +ADD CONSTRAINT "ResourceAccess_pkey" PRIMARY KEY (account_uid, source_local_id, space_id); -ALTER TABLE public."ContentAccess" OWNER TO "postgres"; +ALTER TABLE public."ResourceAccess" OWNER TO "postgres"; -COMMENT ON TABLE public."ContentAccess" IS 'An access control entry for a content'; +COMMENT ON TABLE public."ResourceAccess" IS 'An access control entry for a content'; -COMMENT ON COLUMN public."ContentAccess".content_id IS 'The content item for which access is granted'; +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'; -COMMENT ON COLUMN public."ContentAccess".account_uid IS 'The identity of the user account'; +COMMENT ON COLUMN public."ResourceAccess".account_uid IS 'The identity of the user account'; -ALTER TABLE ONLY public."ContentAccess" -ADD CONSTRAINT "ContentAccess_account_uid_fkey" FOREIGN KEY ( +ALTER TABLE ONLY public."ResourceAccess" +ADD CONSTRAINT "ResourceAccess_account_uid_fkey" FOREIGN KEY ( account_uid ) REFERENCES auth.users (id) ON UPDATE CASCADE ON DELETE CASCADE; -CREATE INDEX content_access_content_id_idx ON public."ContentAccess" (content_id); +CREATE INDEX resource_access_content_local_id_idx ON public."ResourceAccess" (source_local_id, space_id); -ALTER TABLE ONLY public."ContentAccess" -ADD CONSTRAINT "ContentAccess_content_id_fkey" FOREIGN KEY ( - content_id -) REFERENCES public."Content" ( - id -) ON UPDATE CASCADE ON DELETE CASCADE; +-- note that I cannot have a foreign key for Content because the variant is part of the unique key. -GRANT ALL ON TABLE public."ContentAccess" TO authenticated; -GRANT ALL ON TABLE public."ContentAccess" TO service_role; -REVOKE ALL ON TABLE public."ContentAccess" FROM anon; +GRANT ALL ON TABLE public."ResourceAccess" TO authenticated; +GRANT ALL ON TABLE public."ResourceAccess" TO service_role; +REVOKE ALL ON TABLE public."ResourceAccess" FROM anon; REVOKE ALL ON TABLE public."Document" FROM anon; GRANT ALL ON TABLE public."Document" TO authenticated; @@ -208,18 +192,33 @@ REVOKE ALL ON TABLE public."Content" FROM anon; GRANT ALL ON TABLE public."Content" TO authenticated; GRANT ALL ON TABLE public."Content" TO service_role; -CREATE OR REPLACE FUNCTION public.can_view_specific_content(id BIGINT) RETURNS BOOLEAN +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."ContentAccess" + SELECT true FROM public."ResourceAccess" JOIN public.my_user_accounts() ON (account_uid=my_user_accounts) - WHERE content_id=id + WHERE space_id=space_id_ + AND source_local_id = source_local_id_ LIMIT 1); $$; +-- explicit fields require more maintenance, but respects declared table order. +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 @@ -239,7 +238,7 @@ SELECT FROM public."Content" WHERE ( space_id = any(public.my_space_ids()) - OR public.can_view_specific_content(id) + OR public.can_view_specific_resource(space_id, source_local_id) ); CREATE OR REPLACE FUNCTION public.document_of_content(content public.my_contents) @@ -648,13 +647,20 @@ COMMENT ON FUNCTION public.document_in_space IS 'security utility: does current ALTER TABLE public."Document" ENABLE ROW LEVEL SECURITY; DROP POLICY IF EXISTS document_policy ON public."Document"; -CREATE POLICY document_policy ON public."Document" FOR ALL USING (public.in_space(space_id)); +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)); ALTER TABLE public."Content" ENABLE ROW LEVEL SECURITY; DROP POLICY IF EXISTS content_policy ON public."Content"; 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_content(id)); +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_delete_policy ON public."Content"; CREATE POLICY content_delete_policy ON public."Content" FOR DELETE USING (public.in_space(space_id)); DROP POLICY IF EXISTS content_insert_policy ON public."Content"; @@ -662,14 +668,14 @@ CREATE POLICY content_insert_policy ON public."Content" FOR INSERT WITH CHECK (p DROP POLICY IF EXISTS content_update_policy ON public."Content"; CREATE POLICY content_update_policy ON public."Content" FOR UPDATE USING (public.in_space(space_id)); -ALTER TABLE public."ContentAccess" ENABLE ROW LEVEL SECURITY; - -DROP POLICY IF EXISTS content_access_policy ON public."ContentAccess"; -DROP POLICY IF EXISTS content_access_select_policy ON public."ContentAccess"; -CREATE POLICY content_access_select_policy ON public."ContentAccess" FOR SELECT USING (public.content_in_space(content_id) OR public.can_access_account(account_uid)); -DROP POLICY IF EXISTS content_access_delete_policy ON public."ContentAccess"; -CREATE POLICY content_access_delete_policy ON public."ContentAccess" FOR DELETE USING (public.content_in_editable_space(content_id) OR public.can_access_account(account_uid)); -DROP POLICY IF EXISTS content_access_insert_policy ON public."ContentAccess"; -CREATE POLICY content_access_insert_policy ON public."ContentAccess" FOR INSERT WITH CHECK (public.content_in_editable_space(content_id)); -DROP POLICY IF EXISTS content_access_update_policy ON public."ContentAccess"; -CREATE POLICY content_access_update_policy ON public."ContentAccess" FOR UPDATE USING (public.content_in_editable_space(content_id)); +ALTER TABLE public."ResourceAccess" ENABLE ROW LEVEL SECURITY; + +DROP POLICY IF EXISTS resource_access_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));