Skip to content

Commit 4913e56

Browse files
committed
Add triggers to delete ContentAccess when appropriate
1 parent 6b77a2c commit 4913e56

File tree

4 files changed

+249
-1
lines changed

4 files changed

+249
-1
lines changed

packages/database/src/dbTypes.ts

Lines changed: 4 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -1481,6 +1481,10 @@ export type Database = {
14811481
}
14821482
}
14831483
is_group_admin: { Args: { group_id_: string }; Returns: boolean }
1484+
is_last_local_reference: {
1485+
Args: { source_local_id_: string; space_id_: number }
1486+
Returns: boolean
1487+
}
14841488
is_my_account: { Args: { account_id: number }; Returns: boolean }
14851489
match_content_embeddings: {
14861490
Args: {
Lines changed: 171 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,171 @@
1+
DROP TABLE public."ConceptAccess" CASCADE;
2+
3+
ALTER TABLE public."ContentAccess" ADD COLUMN space_id BIGINT;
4+
ALTER TABLE public."ContentAccess" ADD COLUMN source_local_id CHARACTER VARYING;
5+
6+
COMMENT ON COLUMN public."ContentAccess".space_id IS 'The space_id of the content item for which access is granted';
7+
COMMENT ON COLUMN public."ContentAccess".source_local_id IS 'The source_local_id of the content item for which access is granted';
8+
9+
UPDATE public."ContentAccess" AS ca
10+
SET space_id = ct.space_id, source_local_id = ct.source_local_id
11+
FROM public."Content" AS ct WHERE ct.id = content_id;
12+
13+
ALTER TABLE public."ContentAccess" DROP COLUMN content_id CASCADE;
14+
-- cascades to Content policies, indices, primary key...
15+
16+
ALTER TABLE public."ContentAccess" ALTER COLUMN space_id SET NOT NULL;
17+
ALTER TABLE public."ContentAccess" ALTER COLUMN source_local_id SET NOT NULL;
18+
19+
ALTER TABLE ONLY public."ContentAccess"
20+
ADD CONSTRAINT "ContentAccess_pkey" PRIMARY KEY (account_uid, source_local_id, space_id);
21+
22+
CREATE INDEX content_access_content_local_id_idx ON public."ContentAccess" (source_local_id, space_id);
23+
24+
CREATE OR REPLACE FUNCTION public.can_view_specific_content(space_id_ BIGINT, source_local_id_ VARCHAR) RETURNS BOOLEAN
25+
STABLE SECURITY DEFINER
26+
SET search_path = ''
27+
LANGUAGE sql
28+
AS $$
29+
SELECT EXISTS(
30+
SELECT true FROM public."ContentAccess"
31+
JOIN public.my_user_accounts() ON (account_uid=my_user_accounts)
32+
WHERE space_id=space_id_
33+
AND source_local_id = source_local_id_
34+
LIMIT 1);
35+
$$;
36+
37+
CREATE OR REPLACE VIEW public.my_contents AS
38+
SELECT
39+
id,
40+
document_id,
41+
source_local_id,
42+
variant,
43+
author_id,
44+
creator_id,
45+
created,
46+
text,
47+
metadata,
48+
scale,
49+
space_id,
50+
last_modified,
51+
part_of_id
52+
FROM public."Content"
53+
WHERE (
54+
space_id = any(public.my_space_ids())
55+
OR public.can_view_specific_content(space_id, source_local_id)
56+
);
57+
58+
DROP POLICY IF EXISTS document_policy ON public."Document";
59+
DROP POLICY IF EXISTS document_select_policy ON public."Document";
60+
CREATE POLICY document_select_policy ON public."Document" FOR SELECT USING (public.in_space(space_id) OR public.can_view_specific_content(space_id, source_local_id));
61+
DROP POLICY IF EXISTS document_delete_policy ON public."Document";
62+
CREATE POLICY document_delete_policy ON public."Document" FOR DELETE USING (public.in_space(space_id));
63+
DROP POLICY IF EXISTS document_insert_policy ON public."Document";
64+
CREATE POLICY document_insert_policy ON public."Document" FOR INSERT WITH CHECK (public.in_space(space_id));
65+
DROP POLICY IF EXISTS document_update_policy ON public."Document";
66+
CREATE POLICY document_update_policy ON public."Document" FOR UPDATE USING (public.in_space(space_id));
67+
68+
DROP POLICY IF EXISTS content_select_policy ON public."Content";
69+
CREATE POLICY content_select_policy ON public."Content" FOR SELECT USING (public.in_space(space_id) OR public.can_view_specific_content(space_id, source_local_id));
70+
71+
DROP POLICY IF EXISTS content_access_select_policy ON public."ContentAccess";
72+
CREATE POLICY content_access_select_policy ON public."ContentAccess" FOR SELECT USING (public.in_space(space_id) OR public.can_access_account(account_uid));
73+
DROP POLICY IF EXISTS content_access_delete_policy ON public."ContentAccess";
74+
CREATE POLICY content_access_delete_policy ON public."ContentAccess" FOR DELETE USING (public.editor_in_space(space_id) OR public.can_access_account(account_uid));
75+
DROP POLICY IF EXISTS content_access_insert_policy ON public."ContentAccess";
76+
CREATE POLICY content_access_insert_policy ON public."ContentAccess" FOR INSERT WITH CHECK (public.editor_in_space(space_id));
77+
DROP POLICY IF EXISTS content_access_update_policy ON public."ContentAccess";
78+
CREATE POLICY content_access_update_policy ON public."ContentAccess" FOR UPDATE USING (public.editor_in_space(space_id));
79+
80+
DROP FUNCTION public.can_view_specific_content(BIGINT);
81+
82+
CREATE OR REPLACE VIEW public.my_concepts AS
83+
SELECT
84+
id,
85+
epistemic_status,
86+
name,
87+
description,
88+
author_id,
89+
created,
90+
last_modified,
91+
space_id,
92+
arity,
93+
schema_id,
94+
literal_content,
95+
reference_content,
96+
refs,
97+
is_schema,
98+
source_local_id
99+
FROM public."Concept"
100+
WHERE (
101+
space_id = any(public.my_space_ids())
102+
OR public.can_view_specific_content(space_id, source_local_id)
103+
);
104+
105+
106+
DROP POLICY IF EXISTS concept_select_policy ON public."Concept";
107+
CREATE POLICY concept_select_policy ON public."Concept" FOR SELECT USING (public.in_space(space_id) OR public.can_view_specific_content(space_id, source_local_id));
108+
109+
DROP FUNCTION public.can_view_specific_concept(BIGINT);
110+
111+
CREATE OR REPLACE FUNCTION public.is_last_local_reference(space_id_ BIGINT, source_local_id_ VARCHAR) RETURNS boolean
112+
STABLE
113+
SET search_path = ''
114+
SECURITY DEFINER
115+
LANGUAGE sql
116+
AS $$
117+
SELECT NOT EXISTS (SELECT id FROM public."Content" WHERE space_id=space_id_ AND source_local_id=source_local_id_ LIMIT 1)
118+
AND NOT EXISTS (SELECT id FROM public."Concept" WHERE space_id=space_id_ AND source_local_id=source_local_id_)
119+
AND NOT EXISTS (SELECT id FROM public."Document" WHERE space_id=space_id_ AND source_local_id=source_local_id_);
120+
$$;
121+
122+
CREATE OR REPLACE FUNCTION on_delete_local_reference() RETURNS TRIGGER
123+
STABLE
124+
SET search_path = ''
125+
SECURITY DEFINER
126+
LANGUAGE plpgsql
127+
AS $$
128+
BEGIN
129+
IF public.is_last_local_reference(OLD.space_id, OLD.source_local_id) THEN
130+
DELETE FROM public."ContentAccess" WHERE space_id=OLD.space_id AND source_local_id=OLD.source_local_id;
131+
END IF;
132+
RETURN OLD;
133+
END;
134+
$$;
135+
136+
CREATE TRIGGER on_delete_content_trigger AFTER DELETE ON public."Content" FOR EACH ROW EXECUTE FUNCTION public.on_delete_local_reference();
137+
CREATE TRIGGER on_delete_concept_trigger AFTER DELETE ON public."Concept" FOR EACH ROW EXECUTE FUNCTION public.on_delete_local_reference();
138+
CREATE TRIGGER on_delete_document_trigger AFTER DELETE ON public."Document" FOR EACH ROW EXECUTE FUNCTION public.on_delete_local_reference();
139+
140+
CREATE OR REPLACE FUNCTION on_update_local_reference() RETURNS TRIGGER
141+
STABLE
142+
SET search_path = ''
143+
SECURITY DEFINER
144+
LANGUAGE plpgsql
145+
AS $$
146+
BEGIN
147+
IF (OLD.space_id != NEW.space_id OR OLD.source_local_id != NEW.source_local_id)
148+
AND public.is_last_local_reference(OLD.space_id, OLD.source_local_id) THEN
149+
DELETE FROM public."ContentAccess" WHERE space_id=OLD.space_id AND source_local_id=OLD.source_local_id;
150+
END IF;
151+
RETURN NEW;
152+
END;
153+
$$;
154+
155+
CREATE TRIGGER on_update_content_trigger AFTER UPDATE ON public."Content" FOR EACH ROW EXECUTE FUNCTION public.on_update_local_reference();
156+
CREATE TRIGGER on_update_concept_trigger AFTER UPDATE ON public."Concept" FOR EACH ROW EXECUTE FUNCTION public.on_update_local_reference();
157+
CREATE TRIGGER on_update_document_trigger AFTER UPDATE ON public."Document" FOR EACH ROW EXECUTE FUNCTION public.on_update_local_reference();
158+
159+
CREATE OR REPLACE FUNCTION on_delete_space_revoke_local_access() RETURNS TRIGGER
160+
STABLE
161+
SET search_path = ''
162+
SECURITY DEFINER
163+
LANGUAGE plpgsql
164+
AS $$
165+
BEGIN
166+
DELETE FROM public."ContentAccess" WHERE space_id=OLD.space_id;
167+
RETURN OLD;
168+
END;
169+
$$;
170+
171+
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();

packages/database/supabase/schemas/concept.sql

Lines changed: 66 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -415,3 +415,69 @@ DROP POLICY IF EXISTS concept_insert_policy ON public."Concept";
415415
CREATE POLICY concept_insert_policy ON public."Concept" FOR INSERT WITH CHECK (public.in_space(space_id));
416416
DROP POLICY IF EXISTS concept_update_policy ON public."Concept";
417417
CREATE POLICY concept_update_policy ON public."Concept" FOR UPDATE USING (public.in_space(space_id));
418+
419+
-- since ContentAccess is used for both Content and Concepts,
420+
-- we cannot count on the usual foreign key delete cascades.
421+
-- Implementing with triggers
422+
423+
CREATE OR REPLACE FUNCTION public.is_last_local_reference(space_id_ BIGINT, source_local_id_ VARCHAR) RETURNS boolean
424+
STABLE
425+
SET search_path = ''
426+
SECURITY DEFINER
427+
LANGUAGE sql
428+
AS $$
429+
SELECT NOT EXISTS (SELECT id FROM public."Content" WHERE space_id=space_id_ AND source_local_id=source_local_id_ LIMIT 1)
430+
AND NOT EXISTS (SELECT id FROM public."Concept" WHERE space_id=space_id_ AND source_local_id=source_local_id_)
431+
AND NOT EXISTS (SELECT id FROM public."Document" WHERE space_id=space_id_ AND source_local_id=source_local_id_);
432+
$$;
433+
434+
CREATE OR REPLACE FUNCTION on_delete_local_reference() RETURNS TRIGGER
435+
STABLE
436+
SET search_path = ''
437+
SECURITY DEFINER
438+
LANGUAGE plpgsql
439+
AS $$
440+
BEGIN
441+
IF public.is_last_local_reference(OLD.space_id, OLD.source_local_id) THEN
442+
DELETE FROM public."ContentAccess" WHERE space_id=OLD.space_id AND source_local_id=OLD.source_local_id;
443+
END IF;
444+
RETURN OLD;
445+
END;
446+
$$;
447+
448+
CREATE TRIGGER on_delete_content_trigger AFTER DELETE ON public."Content" FOR EACH ROW EXECUTE FUNCTION public.on_delete_local_reference();
449+
CREATE TRIGGER on_delete_concept_trigger AFTER DELETE ON public."Concept" FOR EACH ROW EXECUTE FUNCTION public.on_delete_local_reference();
450+
CREATE TRIGGER on_delete_document_trigger AFTER DELETE ON public."Document" FOR EACH ROW EXECUTE FUNCTION public.on_delete_local_reference();
451+
452+
CREATE OR REPLACE FUNCTION on_update_local_reference() RETURNS TRIGGER
453+
STABLE
454+
SET search_path = ''
455+
SECURITY DEFINER
456+
LANGUAGE plpgsql
457+
AS $$
458+
BEGIN
459+
IF (OLD.space_id != NEW.space_id OR OLD.source_local_id != NEW.source_local_id)
460+
AND public.is_last_local_reference(OLD.space_id, OLD.source_local_id) THEN
461+
DELETE FROM public."ContentAccess" WHERE space_id=OLD.space_id AND source_local_id=OLD.source_local_id;
462+
END IF;
463+
RETURN NEW;
464+
END;
465+
$$;
466+
467+
CREATE TRIGGER on_update_content_trigger AFTER UPDATE ON public."Content" FOR EACH ROW EXECUTE FUNCTION public.on_update_local_reference();
468+
CREATE TRIGGER on_update_concept_trigger AFTER UPDATE ON public."Concept" FOR EACH ROW EXECUTE FUNCTION public.on_update_local_reference();
469+
CREATE TRIGGER on_update_document_trigger AFTER UPDATE ON public."Document" FOR EACH ROW EXECUTE FUNCTION public.on_update_local_reference();
470+
471+
CREATE OR REPLACE FUNCTION on_delete_space_revoke_local_access() RETURNS TRIGGER
472+
STABLE
473+
SET search_path = ''
474+
SECURITY DEFINER
475+
LANGUAGE plpgsql
476+
AS $$
477+
BEGIN
478+
DELETE FROM public."ContentAccess" WHERE space_id=OLD.space_id;
479+
RETURN OLD;
480+
END;
481+
$$;
482+
483+
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();

packages/database/supabase/schemas/content.sql

Lines changed: 8 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -646,7 +646,14 @@ COMMENT ON FUNCTION public.document_in_space IS 'security utility: does current
646646
ALTER TABLE public."Document" ENABLE ROW LEVEL SECURITY;
647647

648648
DROP POLICY IF EXISTS document_policy ON public."Document";
649-
CREATE POLICY document_policy ON public."Document" FOR ALL USING (public.in_space(space_id));
649+
DROP POLICY IF EXISTS document_select_policy ON public."Document";
650+
CREATE POLICY document_select_policy ON public."Document" FOR SELECT USING (public.in_space(space_id) OR public.can_view_specific_content(space_id, source_local_id));
651+
DROP POLICY IF EXISTS document_delete_policy ON public."Document";
652+
CREATE POLICY document_delete_policy ON public."Document" FOR DELETE USING (public.in_space(space_id));
653+
DROP POLICY IF EXISTS document_insert_policy ON public."Document";
654+
CREATE POLICY document_insert_policy ON public."Document" FOR INSERT WITH CHECK (public.in_space(space_id));
655+
DROP POLICY IF EXISTS document_update_policy ON public."Document";
656+
CREATE POLICY document_update_policy ON public."Document" FOR UPDATE USING (public.in_space(space_id));
650657

651658
ALTER TABLE public."Content" ENABLE ROW LEVEL SECURITY;
652659

0 commit comments

Comments
 (0)