- Applied strict RLS and auth validation to tracking/credit services - Set Service Worker to Network First to fix mobile session/loading issues - Expanded Gemini analysis summary to show distilled/bottled/batch info - Updated SQL schema document with hardening policies
434 lines
16 KiB
PL/PgSQL
434 lines
16 KiB
PL/PgSQL
-- Supabase SQL Setup for Whisky Vault
|
|
|
|
-- Profiles table
|
|
CREATE TABLE IF NOT EXISTS profiles (
|
|
id UUID REFERENCES auth.users ON DELETE CASCADE PRIMARY KEY,
|
|
username TEXT UNIQUE,
|
|
avatar_url TEXT,
|
|
updated_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('Europe/Berlin'::text, now())
|
|
);
|
|
|
|
-- Function to handle new user signup
|
|
CREATE OR REPLACE FUNCTION public.handle_new_user()
|
|
RETURNS trigger AS $$
|
|
BEGIN
|
|
INSERT INTO public.profiles (id, username, avatar_url)
|
|
VALUES (
|
|
new.id,
|
|
COALESCE(new.raw_user_meta_data->>'username', 'user_' || substr(new.id::text, 1, 8)),
|
|
new.raw_user_meta_data->>'avatar_url'
|
|
)
|
|
ON CONFLICT (id) DO NOTHING;
|
|
RETURN new;
|
|
END;
|
|
$$ LANGUAGE plpgsql SECURITY DEFINER;
|
|
|
|
-- Manual sync for existing users (Run this once)
|
|
-- INSERT INTO public.profiles (id)
|
|
-- SELECT id FROM auth.users
|
|
-- ON CONFLICT (id) DO NOTHING;
|
|
|
|
-- Bottles table
|
|
CREATE TABLE IF NOT EXISTS bottles (
|
|
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
user_id UUID REFERENCES profiles(id) ON DELETE CASCADE NOT NULL,
|
|
name TEXT NOT NULL,
|
|
distillery TEXT,
|
|
category TEXT, -- Single Malt, Bourbon, etc.
|
|
abv DECIMAL,
|
|
age INTEGER,
|
|
status TEXT DEFAULT 'sealed' CHECK (status IN ('sealed', 'open', 'sampled', 'empty')),
|
|
whiskybase_id TEXT,
|
|
image_url TEXT,
|
|
purchase_price DECIMAL(10, 2),
|
|
is_whisky BOOLEAN DEFAULT true,
|
|
confidence INTEGER DEFAULT 100,
|
|
finished_at TIMESTAMP WITH TIME ZONE,
|
|
distilled_at TEXT,
|
|
bottled_at TEXT,
|
|
batch_info TEXT,
|
|
created_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('Europe/Berlin'::text, now()),
|
|
updated_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('Europe/Berlin'::text, now())
|
|
);
|
|
|
|
-- Buddies table
|
|
CREATE TABLE IF NOT EXISTS buddies (
|
|
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
user_id UUID REFERENCES profiles(id) ON DELETE CASCADE NOT NULL,
|
|
name TEXT NOT NULL,
|
|
buddy_profile_id UUID REFERENCES profiles(id) ON DELETE SET NULL, -- Link to real account
|
|
created_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('Europe/Berlin'::text, now())
|
|
);
|
|
|
|
-- Tasting Sessions table
|
|
CREATE TABLE IF NOT EXISTS tasting_sessions (
|
|
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
user_id UUID REFERENCES profiles(id) ON DELETE CASCADE NOT NULL,
|
|
name TEXT NOT NULL,
|
|
scheduled_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('Europe/Berlin'::text, now()),
|
|
created_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('Europe/Berlin'::text, now())
|
|
);
|
|
|
|
-- Session Participants junction (updated with user_id to avoid RLS recursion)
|
|
CREATE TABLE IF NOT EXISTS session_participants (
|
|
session_id UUID REFERENCES tasting_sessions(id) ON DELETE CASCADE NOT NULL,
|
|
buddy_id UUID REFERENCES buddies(id) ON DELETE CASCADE NOT NULL,
|
|
user_id UUID REFERENCES profiles(id) ON DELETE CASCADE NOT NULL, -- The owner of the session
|
|
PRIMARY KEY (session_id, buddy_id)
|
|
);
|
|
|
|
-- Tastings table (updated with session and buddy tagging)
|
|
CREATE TABLE IF NOT EXISTS tastings (
|
|
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
bottle_id UUID REFERENCES bottles(id) ON DELETE CASCADE NOT NULL,
|
|
user_id UUID REFERENCES profiles(id) ON DELETE CASCADE NOT NULL,
|
|
session_id UUID REFERENCES tasting_sessions(id) ON DELETE SET NULL,
|
|
rating INTEGER CHECK (rating >= 0 AND rating <= 100),
|
|
nose_notes TEXT,
|
|
palate_notes TEXT,
|
|
finish_notes TEXT,
|
|
audio_transcript_url TEXT,
|
|
created_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('Europe/Berlin'::text, now())
|
|
);
|
|
|
|
-- Tasting Tagging (updated with user_id to avoid RLS recursion)
|
|
CREATE TABLE IF NOT EXISTS tasting_tags (
|
|
tasting_id UUID REFERENCES tastings(id) ON DELETE CASCADE NOT NULL,
|
|
buddy_id UUID REFERENCES buddies(id) ON DELETE CASCADE NOT NULL,
|
|
user_id UUID REFERENCES profiles(id) ON DELETE CASCADE NOT NULL, -- The owner of the tasting
|
|
PRIMARY KEY (tasting_id, buddy_id)
|
|
);
|
|
|
|
-- Enable Row Level Security (RLS)
|
|
ALTER TABLE profiles ENABLE ROW LEVEL SECURITY;
|
|
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
|
|
FOR SELECT USING (
|
|
EXISTS (SELECT 1 FROM admin_users WHERE user_id = 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
|
|
FOR UPDATE USING (
|
|
EXISTS (SELECT 1 FROM admin_users WHERE user_id = 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);
|
|
|
|
-- 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
|
|
FOR SELECT USING (
|
|
id IN (
|
|
SELECT tasting_id FROM tasting_tags
|
|
WHERE buddy_id IN (SELECT id FROM buddies WHERE buddy_profile_id = 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);
|
|
|
|
-- 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);
|
|
|
|
-- 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 (
|
|
id IN (
|
|
SELECT session_id FROM session_participants
|
|
WHERE buddy_id IN (SELECT id FROM buddies WHERE buddy_profile_id = 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);
|
|
|
|
-- 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);
|
|
|
|
-- STORAGE SETUP
|
|
-- Create 'bottles' bucket if it doesn't exist
|
|
INSERT INTO storage.buckets (id, name, public)
|
|
VALUES ('bottles', 'bottles', true)
|
|
ON CONFLICT (id) DO NOTHING;
|
|
|
|
-- Policy to allow authenticated users to upload images to their own folder
|
|
-- Falls der Folder-Check zu strikt ist, erlauben wir hier generell Uploads für Authenticated User
|
|
-- Aber wir behalten die Zuordnung im Dateinamen bei.
|
|
CREATE POLICY "Allow authenticated uploads"
|
|
ON storage.objects FOR INSERT
|
|
TO authenticated
|
|
WITH CHECK (
|
|
bucket_id = 'bottles'
|
|
);
|
|
|
|
-- Policy to allow users to update/delete their own images
|
|
CREATE POLICY "Allow users to manage own images"
|
|
ON storage.objects FOR ALL
|
|
TO authenticated
|
|
USING (
|
|
bucket_id = 'bottles' AND
|
|
(storage.foldername(name))[1] = auth.uid()::text
|
|
);
|
|
|
|
-- Policy to allow public to view images
|
|
CREATE POLICY "Allow public view access"
|
|
ON storage.objects FOR SELECT
|
|
TO public
|
|
USING (bucket_id = 'bottles');
|
|
|
|
-- VISION CACHE
|
|
CREATE TABLE IF NOT EXISTS vision_cache (
|
|
hash TEXT PRIMARY KEY,
|
|
result JSONB NOT NULL,
|
|
created_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('utc'::text, now())
|
|
);
|
|
|
|
-- Enable RLS for vision_cache (though it's only accessed via Service Role/Server Actions)
|
|
ALTER TABLE vision_cache ENABLE ROW LEVEL SECURITY;
|
|
|
|
-- Policy to allow authenticated users to view the cache (optional, but good for transparency)
|
|
CREATE POLICY "Allow authenticated users to view cache"
|
|
ON vision_cache FOR SELECT
|
|
TO authenticated
|
|
USING (true);
|
|
|
|
-- ============================================
|
|
-- API Usage Tracking & Credits System
|
|
-- ============================================
|
|
|
|
-- API Usage tracking table
|
|
CREATE TABLE IF NOT EXISTS api_usage (
|
|
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
user_id UUID REFERENCES auth.users(id) ON DELETE CASCADE,
|
|
api_type TEXT NOT NULL CHECK (api_type IN ('google_search', 'gemini_ai')),
|
|
endpoint TEXT,
|
|
success BOOLEAN DEFAULT true,
|
|
error_message TEXT,
|
|
created_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('Europe/Berlin'::text, now())
|
|
);
|
|
|
|
CREATE INDEX idx_api_usage_user_id ON api_usage(user_id);
|
|
CREATE INDEX idx_api_usage_api_type ON api_usage(api_type);
|
|
CREATE INDEX idx_api_usage_created_at ON api_usage(created_at);
|
|
|
|
-- User credits table (for future credits system)
|
|
CREATE TABLE IF NOT EXISTS user_credits (
|
|
user_id UUID PRIMARY KEY REFERENCES auth.users(id) ON DELETE CASCADE,
|
|
balance INTEGER DEFAULT 0,
|
|
total_purchased INTEGER DEFAULT 0,
|
|
total_used INTEGER DEFAULT 0,
|
|
updated_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('Europe/Berlin'::text, now())
|
|
);
|
|
|
|
-- Admin users table
|
|
CREATE TABLE IF NOT EXISTS admin_users (
|
|
user_id UUID PRIMARY KEY REFERENCES auth.users(id) ON DELETE CASCADE,
|
|
role TEXT DEFAULT 'admin' CHECK (role IN ('admin', 'super_admin')),
|
|
created_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('Europe/Berlin'::text, now())
|
|
);
|
|
|
|
-- Enable RLS for API tracking tables
|
|
ALTER TABLE api_usage ENABLE ROW LEVEL SECURITY;
|
|
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 "Users can insert their own API usage" ON api_usage FOR INSERT WITH CHECK (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())
|
|
);
|
|
|
|
-- 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
|
|
);
|
|
|
|
-- Note: To add robin as admin, run this after getting the user_id:
|
|
-- INSERT INTO admin_users (user_id, role) VALUES ('<robin_user_id>', 'super_admin');
|
|
|
|
-- ============================================
|
|
-- Credits Management System
|
|
-- ============================================
|
|
|
|
-- Extend user_credits table with additional fields
|
|
ALTER TABLE user_credits
|
|
ADD COLUMN IF NOT EXISTS daily_limit INTEGER DEFAULT NULL,
|
|
ADD COLUMN IF NOT EXISTS google_search_cost INTEGER DEFAULT 1,
|
|
ADD COLUMN IF NOT EXISTS gemini_ai_cost INTEGER DEFAULT 1,
|
|
ADD COLUMN IF NOT EXISTS last_reset_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('Europe/Berlin'::text, now());
|
|
|
|
-- Credit transactions table
|
|
CREATE TABLE IF NOT EXISTS credit_transactions (
|
|
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
user_id UUID REFERENCES auth.users(id) ON DELETE CASCADE,
|
|
amount INTEGER NOT NULL,
|
|
type TEXT NOT NULL CHECK (type IN ('deduction', 'addition', 'admin_adjustment')),
|
|
reason TEXT,
|
|
api_type TEXT CHECK (api_type IN ('google_search', 'gemini_ai')),
|
|
admin_id UUID REFERENCES auth.users(id),
|
|
balance_after INTEGER,
|
|
created_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('Europe/Berlin'::text, now())
|
|
);
|
|
|
|
CREATE INDEX idx_credit_transactions_user_id ON credit_transactions(user_id);
|
|
CREATE INDEX idx_credit_transactions_created_at ON credit_transactions(created_at);
|
|
CREATE INDEX idx_credit_transactions_type ON credit_transactions(type);
|
|
|
|
-- Enable RLS for credit_transactions
|
|
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
|
|
FOR SELECT USING (
|
|
EXISTS (SELECT 1 FROM admin_users WHERE user_id = auth.uid())
|
|
);
|
|
|
|
CREATE POLICY "Users can insert their own transactions" ON credit_transactions
|
|
FOR INSERT WITH CHECK (auth.uid() = user_id);
|
|
|
|
-- Update user_credits policies to allow admin updates
|
|
CREATE POLICY "Admins can update credits" ON user_credits
|
|
FOR UPDATE USING (
|
|
auth.uid() IN (SELECT user_id FROM admin_users)
|
|
);
|
|
|
|
-- Initialize credits for existing users (run manually if needed)
|
|
-- INSERT INTO user_credits (user_id, balance)
|
|
-- SELECT id, 100
|
|
-- FROM auth.users
|
|
-- ON CONFLICT (user_id) DO UPDATE SET balance = EXCLUDED.balance
|
|
-- WHERE user_credits.balance = 0;
|
|
|
|
-- ============================================
|
|
-- Subscription Plans System
|
|
-- ============================================
|
|
|
|
-- Subscription plans table
|
|
CREATE TABLE IF NOT EXISTS subscription_plans (
|
|
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
name TEXT NOT NULL UNIQUE,
|
|
display_name TEXT NOT NULL,
|
|
monthly_credits INTEGER NOT NULL,
|
|
price DECIMAL(10, 2) DEFAULT 0,
|
|
description TEXT,
|
|
is_active BOOLEAN DEFAULT true,
|
|
sort_order INTEGER DEFAULT 0,
|
|
created_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('Europe/Berlin'::text, now()),
|
|
updated_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('Europe/Berlin'::text, now())
|
|
);
|
|
|
|
CREATE INDEX idx_subscription_plans_active ON subscription_plans(is_active);
|
|
CREATE INDEX idx_subscription_plans_sort_order ON subscription_plans(sort_order);
|
|
|
|
-- User subscriptions table
|
|
CREATE TABLE IF NOT EXISTS user_subscriptions (
|
|
user_id UUID PRIMARY KEY REFERENCES auth.users(id) ON DELETE CASCADE,
|
|
plan_id UUID REFERENCES subscription_plans(id) ON DELETE SET NULL,
|
|
started_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('Europe/Berlin'::text, now()),
|
|
last_credit_grant_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('Europe/Berlin'::text, now()),
|
|
updated_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('Europe/Berlin'::text, now())
|
|
);
|
|
|
|
CREATE INDEX idx_user_subscriptions_plan_id ON user_subscriptions(plan_id);
|
|
|
|
-- Enable RLS
|
|
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 "Admins can manage plans" ON subscription_plans
|
|
FOR ALL USING (
|
|
auth.uid() IN (SELECT user_id FROM admin_users)
|
|
);
|
|
|
|
-- 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
|
|
FOR SELECT USING (
|
|
auth.uid() IN (SELECT user_id FROM admin_users)
|
|
);
|
|
|
|
CREATE POLICY "Admins can manage subscriptions" ON user_subscriptions
|
|
FOR ALL USING (
|
|
auth.uid() IN (SELECT user_id FROM admin_users)
|
|
);
|
|
|
|
-- Insert default plans
|
|
INSERT INTO subscription_plans (name, display_name, monthly_credits, price, description, sort_order) VALUES
|
|
('starter', 'Starter', 10, 0.00, 'Perfect for occasional use', 1),
|
|
('bronze', 'Bronze', 50, 4.99, 'Great for regular users', 2),
|
|
('silver', 'Silver', 100, 8.99, 'Best value for power users', 3),
|
|
('gold', 'Gold', 250, 19.99, 'Unlimited searches for professionals', 4)
|
|
ON CONFLICT (name) DO NOTHING;
|
|
|
|
-- Set all existing users to Starter plan
|
|
INSERT INTO user_subscriptions (user_id, plan_id)
|
|
SELECT
|
|
u.id,
|
|
(SELECT id FROM subscription_plans WHERE name = 'starter' LIMIT 1)
|
|
FROM auth.users u
|
|
ON CONFLICT (user_id) DO NOTHING;
|