Files
Dramlog-Prod/supa_schema.sql

146 lines
4.6 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('utc'::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,
is_whisky BOOLEAN DEFAULT true,
confidence INTEGER DEFAULT 100,
created_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('utc'::text, now()),
updated_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('utc'::text, now())
);
-- Tastings table
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,
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('utc'::text, now())
);
-- 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 "Users can update their own profile" ON profiles
FOR UPDATE USING (auth.uid() = id);
-- 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);
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);
-- 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);