Skip to content

Commit

Permalink
chore: copy migration to schema
Browse files Browse the repository at this point in the history
  • Loading branch information
johannesvedder committed Jun 10, 2024
1 parent 3d4e0b6 commit 7048bbf
Show file tree
Hide file tree
Showing 3 changed files with 151 additions and 48 deletions.
24 changes: 14 additions & 10 deletions database/migration/20240526_migrate_close_study.sql
Original file line number Diff line number Diff line change
Expand Up @@ -6,6 +6,8 @@ CREATE TYPE public.study_status AS ENUM (
'closed'
);

ALTER TYPE public.study_status OWNER TO postgres;

ALTER TABLE public.study
ADD COLUMN status public.study_status DEFAULT 'draft'::public.study_status NOT NULL;

Expand All @@ -17,13 +19,13 @@ UPDATE public.study SET status = CASE
END;

-- Migrate policy
DROP POLICY "Editors can do everything with their studies" ON public.study;
--DROP POLICY "Editors can do everything with their studies" ON public.study;

CREATE POLICY "Editors can view their studies" ON public.study FOR SELECT USING (auth.uid() = user_id);

CREATE POLICY "Editor can control their draft studies" ON public.study
--USING (public.can_edit(auth.uid(), study.*) AND status = 'draft'::public.study_status);
USING (public.can_edit(auth.uid(), study.*));
--CREATE POLICY "Editor can control their draft studies" ON public.study
-- old --USING (public.can_edit(auth.uid(), study.*) AND status = 'draft'::public.study_status);
-- USING (public.can_edit(auth.uid(), study.*));

-- Editors can only update registry_published and resultSharing
--grant update (registry_published, result_sharing) on public.study USING (public.can_edit(auth.uid(), study.*);
Expand All @@ -38,8 +40,7 @@ CREATE POLICY "Editor can control their draft studies" ON public.study

-- https://github.com/orgs/supabase/discussions/656#discussioncomment-5594653

-- todo document this function
CREATE OR REPLACE FUNCTION public.allow_updating_only()
CREATE OR REPLACE FUNCTION public.allow_updating_only_study()
RETURNS trigger
LANGUAGE plpgsql
AS $function$
Expand All @@ -52,17 +53,17 @@ DECLARE
old_value TEXT;
BEGIN

-- If the current user is 'postgres', return NEW without making any changes
-- The user 'postgres' should be able to update any record, e.g. when using Supabase Studio
IF CURRENT_USER = 'postgres' THEN
RETURN NEW;
END IF;

-- If the status is draft, return NEW without making any changes
-- In draft status allow update of all columns
IF OLD.status = 'draft'::public.study_status THEN
RETURN NEW;
END IF;

-- Don't allow invalid status transitions
-- Only allow status to be updated from draft to running and from running to closed
IF OLD.status != NEW.status THEN
IF NOT (
(OLD.status = 'draft'::public.study_status AND NEW.status = 'running'::public.study_status)
Expand Down Expand Up @@ -108,11 +109,14 @@ BEGIN
END;
$function$;

ALTER FUNCTION public.allow_updating_only_study() OWNER TO postgres;

-- Only allow updating status, registry_published and result_sharing of the study table when in draft mode
CREATE OR REPLACE TRIGGER study_status_update_permissions
BEFORE UPDATE
ON public.study
FOR EACH ROW
EXECUTE FUNCTION public.allow_updating_only('updated_at', 'status', 'registry_published', 'result_sharing');
EXECUTE FUNCTION public.allow_updating_only_study('updated_at', 'status', 'registry_published', 'result_sharing');
-- todo also add participation?

-- Owners can update status
Expand Down
174 changes: 137 additions & 37 deletions database/studyu-schema.sql
Original file line number Diff line number Diff line change
Expand Up @@ -66,6 +66,14 @@ CREATE TYPE public.result_sharing AS ENUM (

ALTER TYPE public.result_sharing OWNER TO postgres;

CREATE TYPE public.study_status AS ENUM (
'draft',
'running',
'closed'
);

ALTER TYPE public.study_status OWNER TO postgres;

SET default_tablespace = '';

SET default_table_access_method = heap;
Expand All @@ -82,6 +90,7 @@ CREATE TABLE public.study (
icon_name text NOT NULL,
-- published is deprecated, use status instead
published boolean DEFAULT false NOT NULL,
status public.study_status DEFAULT 'draft'::public.study_status NOT NULL,
registry_published boolean DEFAULT false NOT NULL,
questionnaire jsonb NOT NULL,
eligibility_criteria jsonb NOT NULL,
Expand Down Expand Up @@ -486,6 +495,78 @@ $$;

ALTER FUNCTION public.user_email(user_id uuid) OWNER TO postgres;


CREATE OR REPLACE FUNCTION public.allow_updating_only_study()
RETURNS trigger
LANGUAGE plpgsql
AS $function$
DECLARE
whitelist TEXT[] := TG_ARGV::TEXT[];
schema_table TEXT;
column_name TEXT;
rec RECORD;
new_value TEXT;
old_value TEXT;
BEGIN

-- The user 'postgres' should be able to update any record, e.g. when using Supabase Studio
IF CURRENT_USER = 'postgres' THEN
RETURN NEW;
END IF;

-- In draft status allow update of all columns
IF OLD.status = 'draft'::public.study_status THEN
RETURN NEW;
END IF;

-- Only allow status to be updated from draft to running and from running to closed
IF OLD.status != NEW.status THEN
IF NOT (
(OLD.status = 'draft'::public.study_status AND NEW.status = 'running'::public.study_status)
OR (OLD.status = 'running'::public.study_status AND NEW.status = 'closed'::public.study_status)
) THEN
RAISE EXCEPTION 'Invalid status transition';
END IF;
END IF;

schema_table := concat(TG_TABLE_SCHEMA, '.', TG_TABLE_NAME);

-- If RLS is not active on current table for function invoker, early return
IF NOT row_security_active(schema_table) THEN
RETURN NEW;
END IF;

-- Otherwise, loop on all columns of the table schema
FOR rec IN (
SELECT col.column_name
FROM information_schema.columns as col
WHERE table_schema = TG_TABLE_SCHEMA
AND table_name = TG_TABLE_NAME
) LOOP
-- If the current column is whitelisted, early continue
column_name := rec.column_name;
IF column_name = ANY(whitelist) THEN
CONTINUE;
END IF;

-- If not whitelisted, execute dynamic SQL to get column value from OLD and NEW records
EXECUTE format('SELECT ($1).%I, ($2).%I', column_name, column_name)
INTO new_value, old_value
USING NEW, OLD;

-- Raise exception if column value changed
IF new_value IS DISTINCT FROM old_value THEN
RAISE EXCEPTION 'Unauthorized change to "%"', column_name;
END IF;
END LOOP;

-- RLS active, but no exception encountered, clear to proceed.
RETURN NEW;
END;
$function$;

ALTER FUNCTION public.allow_updating_only_study() OWNER TO postgres;

--
-- Name: app_config; Type: TABLE; Schema: public; Owner: postgres
--
Expand Down Expand Up @@ -686,6 +767,13 @@ CREATE TRIGGER on_auth_user_created AFTER INSERT ON auth.users FOR EACH ROW EXEC

CREATE TRIGGER handle_updated_at BEFORE UPDATE ON public.study FOR EACH ROW EXECUTE FUNCTION extensions.moddatetime('updated_at');

-- Only allow updating status, registry_published and result_sharing of the study table when in draft mode
CREATE OR REPLACE TRIGGER study_status_update_permissions
BEFORE UPDATE
ON public.study
FOR EACH ROW
allow_updating_only_study
EXECUTE FUNCTION public.allow_updating_only_study('updated_at', 'status', 'registry_published', 'result_sharing');

--
-- Name: subject_progress participant_progress_subjectId_fkey; Type: FK CONSTRAINT; Schema: public; Owner: postgres
Expand Down Expand Up @@ -781,6 +869,8 @@ CREATE POLICY "Study creators can do everything with repos from their studies" O
CREATE POLICY "Study subjects can view their joined study" ON public.study FOR SELECT USING (public.is_study_subject_of(auth.uid(), id));


CREATE POLICY "Editors can view their studies" ON public.study FOR SELECT USING (auth.uid() = user_id);

--
-- Name: study Editors can do everything with their studies; Type: POLICY; Schema: public; Owner: postgres
--
Expand Down Expand Up @@ -876,92 +966,102 @@ USING (public.has_results_public(id));
CREATE POLICY "Allow users to manage their own user" ON public."user" FOR ALL USING (auth.uid() = id);

--
-- Name: app_config; Type: ROW SECURITY; Schema: public; Owner: postgres
-- Name: create blob storage bucket for observations; Type: value; Schema: storage; Owner: postgres
--

ALTER TABLE public.app_config ENABLE ROW LEVEL SECURITY;
INSERT INTO storage.buckets (id, name) VALUES ('observations', 'observations');

--
-- Name: repo; Type: ROW SECURITY; Schema: public; Owner: postgres
-- Name: authenticated Users can view their uploaded data; Type: POLICY, Schema: storage
--

ALTER TABLE public.repo ENABLE ROW LEVEL SECURITY;
CREATE POLICY "Allow authenticated Users to view own observations" ON storage.objects FOR
SELECT
TO authenticated USING (((bucket_id = 'observations'::text) AND (owner = auth.uid())));

--
-- Name: study; Type: ROW SECURITY; Schema: public; Owner: postgres
-- Name: authenticated Users can upload observations to storage; Type: POLICY, Schema: storage
--

ALTER TABLE public.study ENABLE ROW LEVEL SECURITY;
CREATE POLICY "Allow authenticated Users to upload observations" ON storage.objects FOR
INSERT
TO authenticated WITH CHECK ((bucket_id = 'observations'::text));

--
-- Name: study_invite; Type: ROW SECURITY; Schema: public; Owner: postgres
-- Name: authenticated Users can delete own observations; Type: POLICY, Schema: storage
--

ALTER TABLE public.study_invite ENABLE ROW LEVEL SECURITY;
CREATE POLICY "Allow authenticated Users to delete own observations" ON storage.objects FOR
DELETE
TO authenticated USING (((bucket_id = 'observations'::text) AND (owner = auth.uid())));

--
-- Name: study_subject; Type: ROW SECURITY; Schema: public; Owner: postgres
-- Name: Researchers can view observations of studies which they created; Type: POLICY, Schema: storage
--

ALTER TABLE public.study_subject ENABLE ROW LEVEL SECURITY;
CREATE POLICY "Allow Researchers to view observations of own studies" ON storage.objects FOR
SELECT
TO public USING (((bucket_id = 'observations'::text) AND
(name ~~ ANY (SELECT ('%'::text || ((public.study.id)::text || '%'::text)) AS study_id
FROM public.study
WHERE ((public.study.user_id)::text = (auth.uid())::text)))));

CREATE POLICY "Joining a closed study should not be possible" ON public.study_subject
AS RESTRICTIVE
FOR INSERT
WITH CHECK (NOT EXISTS (
SELECT 1
FROM public.study
WHERE study.id = study_subject.study_id
AND study.status = 'closed'::public.study_status
));

--
-- Name: subject_progress; Type: ROW SECURITY; Schema: public; Owner: postgres
-- Name: app_config; Type: ROW SECURITY; Schema: public; Owner: postgres
--

ALTER TABLE public.subject_progress ENABLE ROW LEVEL SECURITY;
ALTER TABLE public.app_config ENABLE ROW LEVEL SECURITY;

--
-- Name: user; Type: ROW SECURITY; Schema: public; Owner: postgres
-- Name: repo; Type: ROW SECURITY; Schema: public; Owner: postgres
--

ALTER TABLE public."user" ENABLE ROW LEVEL SECURITY;
ALTER TABLE public.repo ENABLE ROW LEVEL SECURITY;

--
-- Name: study_progress_export; Type: ROW SECURITY; Schema: public; Owner: postgres
-- Name: study; Type: ROW SECURITY; Schema: public; Owner: postgres
--

ALTER VIEW public.study_progress_export SET (security_invoker = on);
ALTER TABLE public.study ENABLE ROW LEVEL SECURITY;

--
-- Name: create blob storage bucket for observations; Type: value; Schema: storage; Owner: postgres
-- Name: study_invite; Type: ROW SECURITY; Schema: public; Owner: postgres
--

INSERT INTO storage.buckets (id, name) VALUES ('observations', 'observations');
ALTER TABLE public.study_invite ENABLE ROW LEVEL SECURITY;

--
-- Name: authenticated Users can view their uploaded data; Type: POLICY, Schema: storage
-- Name: study_subject; Type: ROW SECURITY; Schema: public; Owner: postgres
--

CREATE POLICY "Allow authenticated Users to view own observations" ON storage.objects FOR
SELECT
TO authenticated USING (((bucket_id = 'observations'::text) AND (owner = auth.uid())));
ALTER TABLE public.study_subject ENABLE ROW LEVEL SECURITY;

--
-- Name: authenticated Users can upload observations to storage; Type: POLICY, Schema: storage
-- Name: subject_progress; Type: ROW SECURITY; Schema: public; Owner: postgres
--

CREATE POLICY "Allow authenticated Users to upload observations" ON storage.objects FOR
INSERT
TO authenticated WITH CHECK ((bucket_id = 'observations'::text));
ALTER TABLE public.subject_progress ENABLE ROW LEVEL SECURITY;

--
-- Name: authenticated Users can delete own observations; Type: POLICY, Schema: storage
-- Name: user; Type: ROW SECURITY; Schema: public; Owner: postgres
--

CREATE POLICY "Allow authenticated Users to delete own observations" ON storage.objects FOR
DELETE
TO authenticated USING (((bucket_id = 'observations'::text) AND (owner = auth.uid())));
ALTER TABLE public."user" ENABLE ROW LEVEL SECURITY;

--
-- Name: Researchers can view observations of studies which they created; Type: POLICY, Schema: storage
-- Name: study_progress_export; Type: ROW SECURITY; Schema: public; Owner: postgres
--

CREATE POLICY "Allow Researchers to view observations of own studies" ON storage.objects FOR
SELECT
TO public USING (((bucket_id = 'observations'::text) AND
(name ~~ ANY (SELECT ('%'::text || ((public.study.id)::text || '%'::text)) AS study_id
FROM public.study
WHERE ((public.study.user_id)::text = (auth.uid())::text)))));
ALTER VIEW public.study_progress_export SET (security_invoker = on);

COMMIT;
1 change: 0 additions & 1 deletion supabase/migrations/20240526_migrate_close_study.sql

This file was deleted.

0 comments on commit 7048bbf

Please sign in to comment.