Skip to content

Commit 5e5366d

Browse files
committed
fix rls policies for multiple functions
1 parent 810319e commit 5e5366d

File tree

11 files changed

+784
-253
lines changed

11 files changed

+784
-253
lines changed

prisma/migrations/20250221160426_user_trigger/migration.sql

Lines changed: 221 additions & 62 deletions
Original file line numberDiff line numberDiff line change
@@ -5,86 +5,245 @@
55
-- potentially functions (once we get into RLS functionality). So, for now at least, it seems more
66
-- practical to add the triggers conditionally.
77

8-
-- These triggers automatically create and update a UserProfile when a new user signs up via Supabase Auth.
8+
-- These triggers automatically create and update a Profile when a new user is created via Supabase Auth.
99
-- See https://supabase.com/docs/guides/auth/managing-user-data#using-triggers for more details.
1010

11-
-- inserts a row into public.UserProfiles
12-
13-
create function public.handle_new_user()
14-
returns trigger as $$
15-
begin
16-
insert into public."UserProfiles" ("supId", "supEmail", "supPhone", "name", "email", "phone", "picture", "updatedAt")
17-
values (new.id, new.email, new.phone, new.raw_user_meta_data->>'full_name', new.email, new.phone, coalesce(new.raw_user_meta_data->>'avatar_url', new.raw_user_meta_data->>'picture'), now());
18-
return new;
19-
end;
20-
21-
-- trigger the function above every time an auth.user is created
22-
23-
-- $$ language plpgsql security definer;
24-
-- create trigger on_auth_user_created
25-
-- after insert on auth.users
26-
-- for each row execute procedure public.handle_new_user();
27-
11+
-- Create function to handle new users
12+
DROP FUNCTION IF EXISTS public.handle_new_user();
13+
CREATE OR REPLACE FUNCTION public.handle_new_user()
14+
RETURNS TRIGGER
15+
LANGUAGE plpgsql
16+
SECURITY DEFINER SET search_path = public
17+
AS $$
18+
BEGIN
19+
INSERT INTO "UserProfiles" ("supId", "supEmail", "supPhone", "name", "email", "phone", "picture", "updatedAt")
20+
VALUES (
21+
NEW.id,
22+
NEW.email,
23+
NEW.phone,
24+
COALESCE(NEW.raw_user_meta_data->>'full_name', NEW.raw_user_meta_data->>'name', ''),
25+
NEW.email,
26+
NEW.phone,
27+
COALESCE(NEW.raw_user_meta_data->>'avatar_url', NEW.raw_user_meta_data->>'picture', ''),
28+
NOW()
29+
) ON CONFLICT ("supId") DO NOTHING;
30+
RETURN NEW;
31+
END;
32+
$$;
33+
34+
-- Create function to handle user updates
35+
DROP FUNCTION IF EXISTS public.handle_user_update();
36+
CREATE OR REPLACE FUNCTION public.handle_user_update()
37+
RETURNS TRIGGER
38+
LANGUAGE plpgsql
39+
SECURITY DEFINER SET search_path = public
40+
AS $$
41+
BEGIN
42+
UPDATE "UserProfiles"
43+
SET
44+
"supEmail" = NEW.email,
45+
"supPhone" = NEW.phone,
46+
"name" = COALESCE(NEW.raw_user_meta_data->>'full_name', NEW.raw_user_meta_data->>'name', "name"),
47+
"email" = COALESCE(NEW.email, "email"),
48+
"phone" = COALESCE(NEW.phone, "phone"),
49+
"picture" = COALESCE(NEW.raw_user_meta_data->>'avatar_url', NEW.raw_user_meta_data->>'picture', "picture"),
50+
"updatedAt" = NOW()
51+
WHERE "supId" = NEW.id;
52+
RETURN NEW;
53+
END;
54+
$$;
55+
56+
-- Add explicit policy for triggers to bypass RLS
2857
DO $$
2958
BEGIN
30-
IF EXISTS (SELECT 1 FROM pg_namespace WHERE nspname = 'auth') THEN
31-
EXECUTE 'CREATE TRIGGER on_auth_user_created
32-
AFTER INSERT ON auth.users
33-
FOR EACH ROW EXECUTE PROCEDURE public.handle_new_user();';
59+
-- Check if the UserProfiles table exists
60+
IF EXISTS (
61+
SELECT 1
62+
FROM pg_catalog.pg_class c
63+
JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace
64+
WHERE c.relname = 'UserProfiles'
65+
AND n.nspname = 'public'
66+
) THEN
67+
-- Check if the policy already exists
68+
IF NOT EXISTS (
69+
SELECT 1
70+
FROM pg_catalog.pg_policy p
71+
JOIN pg_catalog.pg_class c ON p.polrelid = c.oid
72+
JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid
73+
WHERE p.polname = 'Allow triggers to manage UserProfiles'
74+
AND c.relname = 'UserProfiles'
75+
AND n.nspname = 'public'
76+
) THEN
77+
-- Create the policy
78+
EXECUTE 'CREATE POLICY "Allow triggers to manage UserProfiles" ON "UserProfiles" USING (true) WITH CHECK (true)';
3479
END IF;
80+
END IF;
3581
END $$;
3682

37-
-- updates a public.UserProfiles' email and phone
38-
39-
create or replace function public.handle_update_user_email_n_phone()
40-
returns trigger as $$
41-
begin
42-
update public."UserProfiles"
43-
set
44-
"supEmail" = coalesce(new.email, "supEmail"),
45-
"supPhone" = coalesce(new.phone, "supPhone")
46-
where "supId" = new.id;
47-
return new;
48-
end;
49-
50-
-- trigger the function above every time an auth.user's email or phone are updated
83+
-- Create a single procedure to manage setting up and removing triggers
84+
DROP PROCEDURE IF EXISTS public.manage_user_triggers();
85+
CREATE OR REPLACE PROCEDURE public.manage_user_triggers()
86+
LANGUAGE plpgsql
87+
AS $$
88+
DECLARE
89+
auth_schema_exists BOOLEAN;
90+
BEGIN
91+
-- Check if auth schema exists (will be false in shadow database)
92+
BEGIN
93+
SELECT EXISTS (SELECT 1 FROM pg_namespace WHERE nspname = 'auth') INTO auth_schema_exists;
94+
EXCEPTION WHEN OTHERS THEN
95+
-- If an error occurs during the check, assume auth schema doesn't exist
96+
RAISE NOTICE 'Error checking for auth schema: %, assuming it does not exist', SQLERRM;
97+
auth_schema_exists := FALSE;
98+
END;
99+
100+
IF auth_schema_exists THEN
101+
BEGIN
102+
-- Remove any existing triggers first
103+
EXECUTE 'DROP TRIGGER IF EXISTS on_auth_user_created ON auth.users;
104+
DROP TRIGGER IF EXISTS on_auth_user_updated ON auth.users;';
105+
106+
-- Create the triggers
107+
EXECUTE 'CREATE TRIGGER on_auth_user_created
108+
AFTER INSERT ON auth.users
109+
FOR EACH ROW EXECUTE FUNCTION public.handle_new_user();
110+
111+
CREATE TRIGGER on_auth_user_updated
112+
AFTER UPDATE ON auth.users
113+
FOR EACH ROW EXECUTE FUNCTION public.handle_user_update();';
114+
115+
-- Grant necessary permissions
116+
BEGIN
117+
EXECUTE 'GRANT EXECUTE ON FUNCTION public.handle_new_user TO authenticated;
118+
GRANT EXECUTE ON FUNCTION public.handle_new_user TO service_role;
119+
GRANT EXECUTE ON FUNCTION public.handle_user_update TO authenticated;
120+
GRANT EXECUTE ON FUNCTION public.handle_user_update TO service_role;';
121+
EXCEPTION
122+
WHEN insufficient_privilege THEN
123+
RAISE NOTICE 'Could not grant EXECUTE permission to roles. This is expected in the shadow database.';
124+
WHEN OTHERS THEN
125+
RAISE NOTICE 'Error granting permissions: %', SQLERRM;
126+
END;
127+
EXCEPTION
128+
WHEN OTHERS THEN
129+
RAISE NOTICE 'Error creating triggers: %. This is expected in the shadow database.', SQLERRM;
130+
END;
131+
ELSE
132+
RAISE NOTICE 'Auth schema does not exist. Skipping trigger creation.';
133+
END IF;
134+
END;
135+
$$;
136+
137+
-- Call the procedure to set up the triggers using a DO block instead of CALL
138+
DO $$
139+
BEGIN
140+
PERFORM public.manage_user_triggers();
141+
EXCEPTION
142+
WHEN OTHERS THEN
143+
RAISE NOTICE 'Error calling manage_user_triggers: %. This is expected in the shadow database.', SQLERRM;
144+
END $$;
51145

52-
-- $$ language plpgsql security definer set search_path = public;
53-
-- create trigger on_auth_user_updated
54-
-- after update of email, phone on auth.users
55-
-- for each row execute procedure public.handle_update_user_email_n_phone();
146+
-- Drop the procedure as we no longer need it after migration
147+
DROP PROCEDURE IF EXISTS public.manage_user_triggers();
56148

149+
-- Create policies to allow users to manage their own profiles
150+
-- These need to align with the RLS policies in enable_rls migration
151+
-- RLS policies don't reference the auth schema directly, so they can be defined unconditionally
57152
DO $$
153+
DECLARE
154+
auth_fn_exists BOOLEAN;
58155
BEGIN
59-
IF EXISTS (SELECT 1 FROM pg_namespace WHERE nspname = 'auth') THEN
60-
EXECUTE 'CREATE TRIGGER on_auth_user_updated
61-
AFTER UPDATE OF email, phone ON auth.users
62-
FOR EACH ROW EXECUTE PROCEDURE public.handle_update_user_email_n_phone();';
156+
-- Check if auth.uid() function exists
157+
BEGIN
158+
SELECT EXISTS (
159+
SELECT 1 FROM pg_proc p
160+
JOIN pg_namespace n ON p.pronamespace = n.oid
161+
WHERE n.nspname = 'auth' AND p.proname = 'uid'
162+
) INTO auth_fn_exists;
163+
EXCEPTION
164+
-- Use standard SQLSTATE error codes instead of named exceptions
165+
WHEN SQLSTATE '3F000' THEN -- schema does not exist
166+
auth_fn_exists := FALSE;
167+
WHEN OTHERS THEN
168+
RAISE NOTICE 'Error checking for auth.uid(): %, assuming it does not exist', SQLERRM;
169+
auth_fn_exists := FALSE;
170+
END;
171+
172+
-- Only attempt to create policies if auth.uid() exists
173+
IF auth_fn_exists THEN
174+
BEGIN
175+
-- Only add the policies if they don't exist already
176+
IF NOT EXISTS (SELECT 1 FROM pg_policy WHERE polname = 'Users can create their own profiles') THEN
177+
EXECUTE $new_policies$
178+
-- Create policy allowing users to create their own profiles
179+
CREATE POLICY "Users can create their own profiles" ON "UserProfiles"
180+
FOR INSERT
181+
WITH CHECK (auth.uid() = "supId");
182+
$new_policies$;
183+
END IF;
184+
185+
-- Only add the policy if it doesn't exist and doesn't conflict with enable_rls
186+
IF NOT EXISTS (SELECT 1 FROM pg_policy WHERE polname = 'Users can view their own profiles') THEN
187+
EXECUTE $new_policies$
188+
-- Create policy allowing users to view their own profiles
189+
CREATE POLICY "Users can view their own profiles" ON "UserProfiles"
190+
FOR SELECT USING (auth.uid() = "supId");
191+
$new_policies$;
192+
END IF;
193+
194+
-- Only add the policy if it doesn't exist and doesn't conflict with enable_rls
195+
IF NOT EXISTS (SELECT 1 FROM pg_policy WHERE polname = 'Users can update their own profile data') THEN
196+
EXECUTE $new_policies$
197+
-- Create policy allowing users to update their own profiles
198+
CREATE POLICY "Users can update their own profile data" ON "UserProfiles"
199+
FOR UPDATE
200+
USING (auth.uid() = "supId")
201+
WITH CHECK (auth.uid() = "supId");
202+
$new_policies$;
203+
END IF;
204+
EXCEPTION
205+
WHEN OTHERS THEN
206+
RAISE NOTICE 'Error creating RLS policies: %. This is expected in the shadow database.', SQLERRM;
207+
END;
208+
ELSE
209+
RAISE NOTICE 'auth.uid() function does not exist. Skipping RLS policy creation.';
63210
END IF;
64211
END $$;
65212

66-
67213
-- Create a trigger to handle the deletion of a user
68-
69-
create or replace function public.handle_delete_user()
70-
returns trigger as $$
71-
begin
72-
delete from public."UserProfiles" where "supId" = old.id;
73-
return old;
74-
end;
214+
CREATE OR REPLACE FUNCTION public.handle_delete_user()
215+
RETURNS TRIGGER AS $$
216+
BEGIN
217+
DELETE FROM public."UserProfiles" WHERE "supId" = OLD.id;
218+
RETURN OLD;
219+
END;
220+
$$ LANGUAGE plpgsql SECURITY DEFINER;
75221

76222
-- Trigger the function above every time an auth.user is deleted
77-
78-
-- $$ language plpgsql security definer set search_path = public;
79-
-- create trigger on_auth_user_deleted
80-
-- after delete on auth.users
81-
-- for each row execute procedure public.handle_delete_user();
82-
83223
DO $$
224+
DECLARE
225+
auth_schema_exists BOOLEAN;
84226
BEGIN
85-
IF EXISTS (SELECT 1 FROM pg_namespace WHERE nspname = 'auth') THEN
86-
EXECUTE 'CREATE TRIGGER on_auth_user_deleted
87-
AFTER DELETE ON auth.users
88-
FOR EACH ROW EXECUTE PROCEDURE public.handle_delete_user();';
227+
BEGIN
228+
SELECT EXISTS (SELECT 1 FROM pg_namespace WHERE nspname = 'auth') INTO auth_schema_exists;
229+
EXCEPTION WHEN OTHERS THEN
230+
auth_schema_exists := FALSE;
231+
END;
232+
233+
IF auth_schema_exists THEN
234+
BEGIN
235+
-- Drop trigger if it exists to avoid conflicts
236+
EXECUTE 'DROP TRIGGER IF EXISTS on_auth_user_deleted ON auth.users;';
237+
238+
-- Create the trigger
239+
EXECUTE 'CREATE TRIGGER on_auth_user_deleted
240+
AFTER DELETE ON auth.users
241+
FOR EACH ROW EXECUTE PROCEDURE public.handle_delete_user();';
242+
EXCEPTION
243+
WHEN OTHERS THEN
244+
RAISE NOTICE 'Error creating delete trigger: %. This is expected in the shadow database.', SQLERRM;
245+
END;
246+
ELSE
247+
RAISE NOTICE 'Auth schema does not exist. Skipping delete trigger creation.';
89248
END IF;
90249
END $$;

prisma/migrations/20250224065512_session_trigger/migration.sql

Lines changed: 27 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -8,6 +8,33 @@
88
-- These triggers automatically create and update a Session when a new session is created via Supabase Auth.
99
-- See https://supabase.com/docs/guides/auth/managing-user-data#using-triggers for more details.
1010

11+
-- Add explicit policy for triggers to bypass RLS for Sessions
12+
DO $$
13+
BEGIN
14+
-- Check if the Sessions table exists
15+
IF EXISTS (
16+
SELECT 1
17+
FROM pg_catalog.pg_class c
18+
JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace
19+
WHERE c.relname = 'Sessions'
20+
AND n.nspname = 'public'
21+
) THEN
22+
-- Check if the policy already exists
23+
IF NOT EXISTS (
24+
SELECT 1
25+
FROM pg_catalog.pg_policy p
26+
JOIN pg_catalog.pg_class c ON p.polrelid = c.oid
27+
JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid
28+
WHERE p.polname = 'Allow triggers to manage Sessions'
29+
AND c.relname = 'Sessions'
30+
AND n.nspname = 'public'
31+
) THEN
32+
-- Create the policy
33+
EXECUTE 'CREATE POLICY "Allow triggers to manage Sessions" ON "Sessions" USING (true) WITH CHECK (true)';
34+
END IF;
35+
END IF;
36+
END $$;
37+
1138
-- Utility function to ensure a user profile exists
1239
DROP FUNCTION IF EXISTS public.ensure_user_profile;
1340
CREATE OR REPLACE FUNCTION public.ensure_user_profile(user_id UUID)

0 commit comments

Comments
 (0)