perf: optimize RLS policies (consolidate and wrap auth calls)
This commit is contained in:
137
supa_schema.sql
137
supa_schema.sql
@@ -105,93 +105,63 @@ ALTER TABLE bottles ENABLE ROW LEVEL SECURITY;
|
||||
ALTER TABLE tastings ENABLE ROW LEVEL SECURITY;
|
||||
|
||||
-- Policies for Profiles
|
||||
CREATE POLICY "Users can view their own profile" ON profiles
|
||||
FOR SELECT USING (auth.uid() = id);
|
||||
|
||||
CREATE POLICY "Admins can view all profiles" ON profiles
|
||||
CREATE POLICY "profiles_select_policy" ON profiles
|
||||
FOR SELECT USING (
|
||||
EXISTS (SELECT 1 FROM admin_users WHERE user_id = auth.uid())
|
||||
(SELECT auth.uid()) = id OR
|
||||
EXISTS (SELECT 1 FROM admin_users WHERE user_id = (SELECT auth.uid()))
|
||||
);
|
||||
|
||||
CREATE POLICY "Users can update their own profile" ON profiles
|
||||
FOR UPDATE USING (auth.uid() = id);
|
||||
|
||||
CREATE POLICY "Admins can update all profiles" ON profiles
|
||||
CREATE POLICY "profiles_update_policy" ON profiles
|
||||
FOR UPDATE USING (
|
||||
EXISTS (SELECT 1 FROM admin_users WHERE user_id = auth.uid())
|
||||
(SELECT auth.uid()) = id OR
|
||||
EXISTS (SELECT 1 FROM admin_users WHERE user_id = (SELECT auth.uid()))
|
||||
);
|
||||
|
||||
-- Policies for Bottles
|
||||
CREATE POLICY "Users can view their own bottles" ON bottles
|
||||
FOR SELECT USING (auth.uid() = user_id);
|
||||
|
||||
CREATE POLICY "Users can insert their own bottles" ON bottles
|
||||
FOR INSERT WITH CHECK (auth.uid() = user_id);
|
||||
|
||||
CREATE POLICY "Users can update their own bottles" ON bottles
|
||||
FOR UPDATE USING (auth.uid() = user_id);
|
||||
|
||||
CREATE POLICY "Users can delete their own bottles" ON bottles
|
||||
FOR DELETE USING (auth.uid() = user_id);
|
||||
CREATE POLICY "bottles_owner_policy" ON bottles
|
||||
FOR ALL USING ((SELECT auth.uid()) = user_id);
|
||||
|
||||
-- Policies for Tastings
|
||||
CREATE POLICY "Users can view their own tastings" ON tastings
|
||||
FOR SELECT USING (auth.uid() = user_id);
|
||||
|
||||
-- Geteilte Tastings für Buddies sichtbar machen (wenn verknüpft)
|
||||
CREATE POLICY "Users can view tastings they are tagged in" ON tastings
|
||||
CREATE POLICY "tastings_select_policy" ON tastings
|
||||
FOR SELECT USING (
|
||||
(SELECT auth.uid()) = user_id OR
|
||||
id IN (
|
||||
SELECT tasting_id FROM tasting_tags
|
||||
WHERE buddy_id IN (SELECT id FROM buddies WHERE buddy_profile_id = auth.uid())
|
||||
WHERE buddy_id IN (SELECT id FROM buddies WHERE buddy_profile_id = (SELECT auth.uid()))
|
||||
)
|
||||
);
|
||||
|
||||
CREATE POLICY "Users can insert their own tastings" ON tastings
|
||||
FOR INSERT WITH CHECK (auth.uid() = user_id);
|
||||
|
||||
CREATE POLICY "Users can update their own tastings" ON tastings
|
||||
FOR UPDATE USING (auth.uid() = user_id);
|
||||
|
||||
CREATE POLICY "Users can delete their own tastings" ON tastings
|
||||
FOR DELETE USING (auth.uid() = user_id);
|
||||
CREATE POLICY "tastings_modify_policy" ON tastings
|
||||
FOR ALL USING ((SELECT auth.uid()) = user_id);
|
||||
|
||||
-- Policies for Buddies
|
||||
ALTER TABLE buddies ENABLE ROW LEVEL SECURITY;
|
||||
CREATE POLICY "Users can manage their own buddies" ON buddies
|
||||
FOR ALL USING (auth.uid() = user_id);
|
||||
CREATE POLICY "Users can see buddies linked to their profile" ON buddies
|
||||
FOR SELECT USING (buddy_profile_id = auth.uid());
|
||||
|
||||
-- TASTINGS (Core Table)
|
||||
ALTER TABLE tastings ENABLE ROW LEVEL SECURITY;
|
||||
|
||||
-- SIMPLEST POLICY: You see your own stuff.
|
||||
-- No subqueries = No recursion.
|
||||
CREATE POLICY "tastings_owner_policy" ON tastings
|
||||
FOR ALL USING (auth.uid() = user_id);
|
||||
CREATE POLICY "buddies_access_policy" ON buddies
|
||||
FOR ALL USING (
|
||||
(SELECT auth.uid()) = user_id OR
|
||||
buddy_profile_id = (SELECT auth.uid())
|
||||
);
|
||||
|
||||
-- Policies for Tasting Sessions
|
||||
ALTER TABLE tasting_sessions ENABLE ROW LEVEL SECURITY;
|
||||
CREATE POLICY "Users can manage their own sessions" ON tasting_sessions
|
||||
FOR ALL USING (auth.uid() = user_id);
|
||||
CREATE POLICY "Users can see sessions they participate in" ON tasting_sessions
|
||||
FOR SELECT USING (
|
||||
CREATE POLICY "sessions_access_policy" ON tasting_sessions
|
||||
FOR ALL USING (
|
||||
(SELECT auth.uid()) = user_id OR
|
||||
id IN (
|
||||
SELECT session_id FROM session_participants
|
||||
WHERE buddy_id IN (SELECT id FROM buddies WHERE buddy_profile_id = auth.uid())
|
||||
WHERE buddy_id IN (SELECT id FROM buddies WHERE buddy_profile_id = (SELECT auth.uid()))
|
||||
)
|
||||
);
|
||||
|
||||
-- SESSION PARTICIPANTS
|
||||
ALTER TABLE session_participants ENABLE ROW LEVEL SECURITY;
|
||||
CREATE POLICY "session_participants_owner_policy" ON session_participants
|
||||
FOR ALL USING (auth.uid() = user_id);
|
||||
FOR ALL USING ((SELECT auth.uid()) = user_id);
|
||||
|
||||
-- TASTING TAGS
|
||||
ALTER TABLE tasting_tags ENABLE ROW LEVEL SECURITY;
|
||||
CREATE POLICY "tasting_tags_owner_policy" ON tasting_tags
|
||||
FOR ALL USING (auth.uid() = user_id);
|
||||
FOR ALL USING ((SELECT auth.uid()) = user_id);
|
||||
|
||||
-- STORAGE SETUP
|
||||
-- Create 'bottles' bucket if it doesn't exist
|
||||
@@ -215,7 +185,7 @@ ON storage.objects FOR ALL
|
||||
TO authenticated
|
||||
USING (
|
||||
bucket_id = 'bottles' AND
|
||||
(storage.foldername(name))[1] = auth.uid()::text
|
||||
(storage.foldername(name))[1] = (SELECT auth.uid())::text
|
||||
);
|
||||
|
||||
-- Policy to allow public to view images
|
||||
@@ -281,21 +251,21 @@ ALTER TABLE user_credits ENABLE ROW LEVEL SECURITY;
|
||||
ALTER TABLE admin_users ENABLE ROW LEVEL SECURITY;
|
||||
|
||||
-- Policies for api_usage (users can view their own, admins can view all)
|
||||
CREATE POLICY "Users can view their own API usage" ON api_usage FOR SELECT USING (auth.uid() = user_id);
|
||||
CREATE POLICY "Admins can view all API usage" ON api_usage FOR SELECT USING (
|
||||
EXISTS (SELECT 1 FROM admin_users WHERE user_id = auth.uid())
|
||||
CREATE POLICY "api_usage_select_policy" ON api_usage FOR SELECT USING (
|
||||
(SELECT auth.uid()) = user_id OR
|
||||
EXISTS (SELECT 1 FROM admin_users WHERE user_id = (SELECT auth.uid()))
|
||||
);
|
||||
CREATE POLICY "Users can insert their own API usage" ON api_usage FOR INSERT WITH CHECK (auth.uid() = user_id);
|
||||
CREATE POLICY "api_usage_insert_policy" ON api_usage FOR INSERT WITH CHECK ((SELECT auth.uid()) = user_id);
|
||||
|
||||
-- Policies for user_credits
|
||||
CREATE POLICY "Users can view their own credits" ON user_credits FOR SELECT USING (auth.uid() = user_id);
|
||||
CREATE POLICY "Admins can view all credits" ON user_credits FOR SELECT USING (
|
||||
EXISTS (SELECT 1 FROM admin_users WHERE user_id = auth.uid())
|
||||
CREATE POLICY "user_credits_select_policy" ON user_credits FOR SELECT USING (
|
||||
(SELECT auth.uid()) = user_id OR
|
||||
EXISTS (SELECT 1 FROM admin_users WHERE user_id = (SELECT auth.uid()))
|
||||
);
|
||||
|
||||
-- Policies for admin_users (users can see their own admin record)
|
||||
CREATE POLICY "Users can view their own admin record" ON admin_users FOR SELECT USING (
|
||||
auth.uid() = user_id
|
||||
CREATE POLICY "admin_users_select_policy" ON admin_users FOR SELECT USING (
|
||||
(SELECT auth.uid()) = user_id
|
||||
);
|
||||
|
||||
-- Note: To add robin as admin, run this after getting the user_id:
|
||||
@@ -333,21 +303,19 @@ CREATE INDEX idx_credit_transactions_type ON credit_transactions(type);
|
||||
ALTER TABLE credit_transactions ENABLE ROW LEVEL SECURITY;
|
||||
|
||||
-- Policies for credit_transactions
|
||||
CREATE POLICY "Users can view their own transactions" ON credit_transactions
|
||||
FOR SELECT USING (auth.uid() = user_id);
|
||||
|
||||
CREATE POLICY "Admins can view all transactions" ON credit_transactions
|
||||
CREATE POLICY "credit_transactions_select_policy" ON credit_transactions
|
||||
FOR SELECT USING (
|
||||
EXISTS (SELECT 1 FROM admin_users WHERE user_id = auth.uid())
|
||||
(SELECT auth.uid()) = user_id OR
|
||||
EXISTS (SELECT 1 FROM admin_users WHERE user_id = (SELECT auth.uid()))
|
||||
);
|
||||
|
||||
CREATE POLICY "Users can insert their own transactions" ON credit_transactions
|
||||
FOR INSERT WITH CHECK (auth.uid() = user_id);
|
||||
CREATE POLICY "credit_transactions_insert_policy" ON credit_transactions
|
||||
FOR INSERT WITH CHECK ((SELECT auth.uid()) = user_id);
|
||||
|
||||
-- Update user_credits policies to allow admin updates
|
||||
CREATE POLICY "Admins can update credits" ON user_credits
|
||||
CREATE POLICY "user_credits_update_policy" ON user_credits
|
||||
FOR UPDATE USING (
|
||||
auth.uid() IN (SELECT user_id FROM admin_users)
|
||||
EXISTS (SELECT 1 FROM admin_users WHERE user_id = (SELECT auth.uid()))
|
||||
);
|
||||
|
||||
-- Initialize credits for existing users (run manually if needed)
|
||||
@@ -394,26 +362,27 @@ ALTER TABLE subscription_plans ENABLE ROW LEVEL SECURITY;
|
||||
ALTER TABLE user_subscriptions ENABLE ROW LEVEL SECURITY;
|
||||
|
||||
-- Policies for subscription_plans (everyone can view active plans)
|
||||
CREATE POLICY "Anyone can view active plans" ON subscription_plans
|
||||
FOR SELECT USING (is_active = true);
|
||||
CREATE POLICY "subscription_plans_select_policy" ON subscription_plans
|
||||
FOR SELECT USING (
|
||||
is_active = true OR
|
||||
EXISTS (SELECT 1 FROM admin_users WHERE user_id = (SELECT auth.uid()))
|
||||
);
|
||||
|
||||
CREATE POLICY "Admins can manage plans" ON subscription_plans
|
||||
CREATE POLICY "subscription_plans_admin_policy" ON subscription_plans
|
||||
FOR ALL USING (
|
||||
auth.uid() IN (SELECT user_id FROM admin_users)
|
||||
EXISTS (SELECT 1 FROM admin_users WHERE user_id = (SELECT auth.uid()))
|
||||
);
|
||||
|
||||
-- Policies for user_subscriptions
|
||||
CREATE POLICY "Users can view their own subscription" ON user_subscriptions
|
||||
FOR SELECT USING (auth.uid() = user_id);
|
||||
|
||||
CREATE POLICY "Admins can view all subscriptions" ON user_subscriptions
|
||||
CREATE POLICY "user_subscriptions_select_policy" ON user_subscriptions
|
||||
FOR SELECT USING (
|
||||
auth.uid() IN (SELECT user_id FROM admin_users)
|
||||
(SELECT auth.uid()) = user_id OR
|
||||
EXISTS (SELECT 1 FROM admin_users WHERE user_id = (SELECT auth.uid()))
|
||||
);
|
||||
|
||||
CREATE POLICY "Admins can manage subscriptions" ON user_subscriptions
|
||||
CREATE POLICY "user_subscriptions_admin_policy" ON user_subscriptions
|
||||
FOR ALL USING (
|
||||
auth.uid() IN (SELECT user_id FROM admin_users)
|
||||
EXISTS (SELECT 1 FROM admin_users WHERE user_id = (SELECT auth.uid()))
|
||||
);
|
||||
|
||||
-- Insert default plans
|
||||
|
||||
Reference in New Issue
Block a user