Refactor: Centralized Supabase Auth and implemented Auth Guards to prevent 401 errors
This commit is contained in:
725
supa_schema.sql
725
supa_schema.sql
@@ -1,40 +1,33 @@
|
||||
-- Supabase SQL Setup for Whisky Vault
|
||||
-- ============================================
|
||||
-- Supabase SQL Setup for Whisky Vault (Consolidated)
|
||||
-- ============================================
|
||||
|
||||
-- Profiles table
|
||||
CREATE TABLE IF NOT EXISTS profiles (
|
||||
-- 1. EXTENSIONS
|
||||
CREATE EXTENSION IF NOT EXISTS "uuid-ossp";
|
||||
|
||||
-- 2. ENUM (Must be created first)
|
||||
-- If this fails because the type exists, you can safely skip this line.
|
||||
CREATE TYPE public.tag_category AS ENUM ('nose', 'taste', 'finish', 'texture');
|
||||
|
||||
-- ============================================
|
||||
-- 3. TABLES (Ordered by Dependencies)
|
||||
-- ============================================
|
||||
|
||||
-- Profiles
|
||||
CREATE TABLE IF NOT EXISTS public.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 SET search_path = '';
|
||||
|
||||
-- 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 (
|
||||
-- Bottles
|
||||
CREATE TABLE IF NOT EXISTS public.bottles (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
user_id UUID REFERENCES profiles(id) ON DELETE CASCADE NOT NULL,
|
||||
user_id UUID REFERENCES public.profiles(id) ON DELETE CASCADE NOT NULL,
|
||||
name TEXT NOT NULL,
|
||||
distillery TEXT,
|
||||
category TEXT, -- Single Malt, Bourbon, etc.
|
||||
category TEXT,
|
||||
abv DECIMAL,
|
||||
age INTEGER,
|
||||
status TEXT DEFAULT 'sealed' CHECK (status IN ('sealed', 'open', 'sampled', 'empty')),
|
||||
@@ -48,308 +41,110 @@ CREATE TABLE IF NOT EXISTS bottles (
|
||||
distilled_at TEXT,
|
||||
bottled_at TEXT,
|
||||
batch_info TEXT,
|
||||
suggested_tags 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 (
|
||||
-- Buddies
|
||||
CREATE TABLE IF NOT EXISTS public.buddies (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
user_id UUID REFERENCES profiles(id) ON DELETE CASCADE NOT NULL,
|
||||
user_id UUID REFERENCES public.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
|
||||
buddy_profile_id UUID REFERENCES public.profiles(id) ON DELETE SET NULL,
|
||||
created_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('Europe/Berlin'::text, now())
|
||||
);
|
||||
|
||||
-- Tasting Sessions table
|
||||
CREATE TABLE IF NOT EXISTS tasting_sessions (
|
||||
-- Tasting Sessions
|
||||
CREATE TABLE IF NOT EXISTS public.tasting_sessions (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
user_id UUID REFERENCES profiles(id) ON DELETE CASCADE NOT NULL,
|
||||
user_id UUID REFERENCES public.profiles(id) ON DELETE CASCADE NOT NULL,
|
||||
name TEXT NOT NULL,
|
||||
scheduled_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('Europe/Berlin'::text, now()),
|
||||
started_at TIMESTAMP WITH TIME ZONE,
|
||||
ended_at TIMESTAMP WITH TIME ZONE,
|
||||
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
|
||||
-- Session Participants
|
||||
CREATE TABLE IF NOT EXISTS public.session_participants (
|
||||
session_id UUID REFERENCES public.tasting_sessions(id) ON DELETE CASCADE NOT NULL,
|
||||
buddy_id UUID REFERENCES public.buddies(id) ON DELETE CASCADE NOT NULL,
|
||||
user_id UUID REFERENCES public.profiles(id) ON DELETE CASCADE NOT NULL,
|
||||
PRIMARY KEY (session_id, buddy_id)
|
||||
);
|
||||
|
||||
-- Tastings table (updated with session and buddy tagging)
|
||||
CREATE TABLE IF NOT EXISTS tastings (
|
||||
-- Tastings
|
||||
CREATE TABLE IF NOT EXISTS public.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,
|
||||
bottle_id UUID REFERENCES public.bottles(id) ON DELETE CASCADE NOT NULL,
|
||||
user_id UUID REFERENCES public.profiles(id) ON DELETE CASCADE NOT NULL,
|
||||
session_id UUID REFERENCES public.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,
|
||||
tasted_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('Europe/Berlin'::text, now()),
|
||||
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
|
||||
DROP POLICY IF EXISTS "profiles_select_policy" ON profiles;
|
||||
CREATE POLICY "profiles_select_policy" ON profiles
|
||||
FOR SELECT USING (
|
||||
(SELECT auth.uid()) = id OR
|
||||
EXISTS (SELECT 1 FROM admin_users WHERE user_id = (SELECT auth.uid()))
|
||||
);
|
||||
|
||||
DROP POLICY IF EXISTS "profiles_update_policy" ON profiles;
|
||||
CREATE POLICY "profiles_update_policy" ON profiles
|
||||
FOR UPDATE USING (
|
||||
(SELECT auth.uid()) = id OR
|
||||
EXISTS (SELECT 1 FROM admin_users WHERE user_id = (SELECT auth.uid()))
|
||||
);
|
||||
|
||||
-- Policies for Bottles
|
||||
DROP POLICY IF EXISTS "Relaxed bottles access" ON bottles;
|
||||
DROP POLICY IF EXISTS "bottles_owner_policy" ON bottles;
|
||||
CREATE POLICY "bottles_owner_policy" ON bottles
|
||||
FOR ALL USING ((SELECT auth.uid()) = user_id);
|
||||
|
||||
-- Policies for Tastings
|
||||
DROP POLICY IF EXISTS "tastings_owner_all" ON tastings;
|
||||
DROP POLICY IF EXISTS "tastings_select_policy" 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 = (SELECT auth.uid()))
|
||||
)
|
||||
);
|
||||
|
||||
DROP POLICY IF EXISTS "tastings_modify_policy" ON tastings;
|
||||
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;
|
||||
DROP POLICY IF EXISTS "Manage own buddies" ON buddies;
|
||||
DROP POLICY IF EXISTS "buddies_access_policy" ON buddies;
|
||||
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;
|
||||
DROP POLICY IF EXISTS "Manage own sessions" ON tasting_sessions;
|
||||
DROP POLICY IF EXISTS "sessions_access_policy" ON tasting_sessions;
|
||||
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 = (SELECT auth.uid()))
|
||||
)
|
||||
);
|
||||
|
||||
-- SESSION PARTICIPANTS
|
||||
ALTER TABLE session_participants ENABLE ROW LEVEL SECURITY;
|
||||
DROP POLICY IF EXISTS "session_owner_all" ON session_participants;
|
||||
DROP POLICY IF EXISTS "session_participants_owner_policy" ON session_participants;
|
||||
CREATE POLICY "session_participants_owner_policy" ON session_participants
|
||||
FOR ALL USING ((SELECT auth.uid()) = user_id);
|
||||
|
||||
-- TASTING TAGS
|
||||
ALTER TABLE tasting_tags ENABLE ROW LEVEL SECURITY;
|
||||
DROP POLICY IF EXISTS "tags_owner_all" ON tasting_tags;
|
||||
DROP POLICY IF EXISTS "tasting_tags_owner_policy" ON tasting_tags;
|
||||
CREATE POLICY "tasting_tags_owner_policy" ON tasting_tags
|
||||
FOR ALL USING ((SELECT 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] = (SELECT 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 (
|
||||
-- Tags Master
|
||||
CREATE TABLE IF NOT EXISTS public.tags (
|
||||
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,
|
||||
model TEXT,
|
||||
provider TEXT,
|
||||
response_text TEXT,
|
||||
created_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('Europe/Berlin'::text, now())
|
||||
name TEXT NOT NULL,
|
||||
category public.tag_category NOT NULL,
|
||||
is_system_default BOOLEAN DEFAULT false,
|
||||
popularity_score INTEGER DEFAULT 3,
|
||||
created_by UUID REFERENCES public.profiles(id) ON DELETE CASCADE,
|
||||
UNIQUE(name, category)
|
||||
);
|
||||
|
||||
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())
|
||||
-- Junction Tables
|
||||
CREATE TABLE IF NOT EXISTS public.tasting_tags (
|
||||
tasting_id UUID REFERENCES public.tastings(id) ON DELETE CASCADE NOT NULL,
|
||||
tag_id UUID REFERENCES public.tags(id) ON DELETE CASCADE NOT NULL,
|
||||
user_id UUID REFERENCES public.profiles(id) ON DELETE CASCADE NOT NULL,
|
||||
PRIMARY KEY (tasting_id, tag_id)
|
||||
);
|
||||
|
||||
-- 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())
|
||||
CREATE TABLE IF NOT EXISTS public.tasting_buddies (
|
||||
tasting_id UUID REFERENCES public.tastings(id) ON DELETE CASCADE NOT NULL,
|
||||
buddy_id UUID REFERENCES public.buddies(id) ON DELETE CASCADE NOT NULL,
|
||||
user_id UUID REFERENCES public.profiles(id) ON DELETE CASCADE NOT NULL,
|
||||
PRIMARY KEY (tasting_id, buddy_id)
|
||||
);
|
||||
|
||||
-- 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 "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 "api_usage_insert_policy" ON api_usage FOR INSERT WITH CHECK ((SELECT auth.uid()) = user_id);
|
||||
|
||||
-- Policies for user_credits
|
||||
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()))
|
||||
-- Bottle Splits
|
||||
CREATE TABLE IF NOT EXISTS public.bottle_splits (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
bottle_id UUID REFERENCES public.bottles(id) ON DELETE CASCADE UNIQUE,
|
||||
host_id UUID REFERENCES public.profiles(id) ON DELETE CASCADE NOT NULL,
|
||||
total_volume INTEGER DEFAULT 70,
|
||||
host_share INTEGER DEFAULT 10,
|
||||
price_bottle DECIMAL(10, 2) NOT NULL,
|
||||
sample_sizes JSONB DEFAULT '[{"cl": 5, "glass_cost": 0.80}, {"cl": 10, "glass_cost": 1.50}]'::jsonb,
|
||||
shipping_options JSONB DEFAULT '[]'::jsonb,
|
||||
is_active BOOLEAN DEFAULT true,
|
||||
public_slug TEXT UNIQUE NOT NULL,
|
||||
created_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('Europe/Berlin'::text, now()),
|
||||
updated_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('Europe/Berlin'::text, now())
|
||||
);
|
||||
|
||||
-- Policies for admin_users (users can see their own admin record)
|
||||
CREATE POLICY "admin_users_select_policy" ON admin_users FOR SELECT USING (
|
||||
(SELECT auth.uid()) = user_id
|
||||
CREATE TABLE IF NOT EXISTS public.split_participants (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
split_id UUID REFERENCES public.bottle_splits(id) ON DELETE CASCADE NOT NULL,
|
||||
user_id UUID REFERENCES public.profiles(id) ON DELETE CASCADE NOT NULL,
|
||||
amount_cl INTEGER NOT NULL CHECK (amount_cl > 0),
|
||||
shipping_method TEXT NOT NULL,
|
||||
total_cost DECIMAL(10, 2) NOT NULL,
|
||||
status TEXT DEFAULT 'PENDING' CHECK (status IN ('PENDING', 'APPROVED', 'PAID', 'SHIPPED', 'REJECTED', 'WAITLIST')),
|
||||
created_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('Europe/Berlin'::text, now()),
|
||||
UNIQUE(split_id, 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 "credit_transactions_select_policy" ON credit_transactions
|
||||
FOR SELECT USING (
|
||||
(SELECT auth.uid()) = user_id OR
|
||||
EXISTS (SELECT 1 FROM admin_users WHERE user_id = (SELECT auth.uid()))
|
||||
);
|
||||
|
||||
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 "user_credits_update_policy" ON user_credits
|
||||
FOR UPDATE USING (
|
||||
EXISTS (SELECT 1 FROM admin_users WHERE user_id = (SELECT auth.uid()))
|
||||
);
|
||||
|
||||
-- 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 (
|
||||
-- Subscriptions & Credits
|
||||
CREATE TABLE IF NOT EXISTS public.subscription_plans (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
name TEXT NOT NULL UNIQUE,
|
||||
display_name TEXT NOT NULL,
|
||||
@@ -362,161 +157,231 @@ CREATE TABLE IF NOT EXISTS subscription_plans (
|
||||
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 (
|
||||
CREATE TABLE IF NOT EXISTS public.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,
|
||||
plan_id UUID REFERENCES public.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 "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 TABLE IF NOT EXISTS public.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,
|
||||
daily_limit INTEGER DEFAULT NULL,
|
||||
google_search_cost INTEGER DEFAULT 1,
|
||||
gemini_ai_cost INTEGER DEFAULT 1,
|
||||
last_reset_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('Europe/Berlin'::text, now()),
|
||||
updated_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('Europe/Berlin'::text, now())
|
||||
);
|
||||
|
||||
CREATE POLICY "subscription_plans_admin_policy" ON subscription_plans
|
||||
FOR ALL USING (
|
||||
EXISTS (SELECT 1 FROM admin_users WHERE user_id = (SELECT auth.uid()))
|
||||
CREATE TABLE IF NOT EXISTS public.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())
|
||||
);
|
||||
|
||||
-- Policies for user_subscriptions
|
||||
CREATE POLICY "user_subscriptions_select_policy" ON user_subscriptions
|
||||
FOR SELECT USING (
|
||||
(SELECT auth.uid()) = user_id OR
|
||||
EXISTS (SELECT 1 FROM admin_users WHERE user_id = (SELECT auth.uid()))
|
||||
-- Admin & Utility
|
||||
CREATE TABLE IF NOT EXISTS public.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())
|
||||
);
|
||||
|
||||
CREATE POLICY "user_subscriptions_admin_policy" ON user_subscriptions
|
||||
FOR ALL USING (
|
||||
EXISTS (SELECT 1 FROM admin_users WHERE user_id = (SELECT auth.uid()))
|
||||
CREATE TABLE IF NOT EXISTS public.vision_cache (
|
||||
hash TEXT PRIMARY KEY,
|
||||
result JSONB NOT NULL,
|
||||
created_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('utc'::text, now())
|
||||
);
|
||||
|
||||
-- Insert default plans
|
||||
INSERT INTO subscription_plans (name, display_name, monthly_credits, price, description, sort_order) VALUES
|
||||
CREATE TABLE IF NOT EXISTS public.global_products (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
wb_id TEXT UNIQUE NOT NULL,
|
||||
full_name TEXT NOT NULL,
|
||||
search_vector tsvector GENERATED ALWAYS AS (to_tsvector('simple', full_name)) STORED,
|
||||
image_hash TEXT,
|
||||
created_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('utc'::text, now())
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS public.enrichment_cache (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
distillery TEXT NOT NULL UNIQUE,
|
||||
suggested_tags TEXT[],
|
||||
suggested_custom_tags TEXT[],
|
||||
search_string TEXT,
|
||||
created_at TIMESTAMPTZ DEFAULT now(),
|
||||
updated_at TIMESTAMPTZ DEFAULT now(),
|
||||
hit_count INTEGER DEFAULT 0
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS public.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,
|
||||
model TEXT,
|
||||
provider TEXT,
|
||||
response_text TEXT,
|
||||
created_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('Europe/Berlin'::text, now())
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS public.buddy_invites (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
creator_id UUID REFERENCES public.profiles(id) ON DELETE CASCADE NOT NULL,
|
||||
code TEXT NOT NULL UNIQUE,
|
||||
expires_at TIMESTAMP WITH TIME ZONE NOT NULL,
|
||||
created_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('Europe/Berlin'::text, now())
|
||||
);
|
||||
|
||||
-- ============================================
|
||||
-- 4. FUNCTIONS & TRIGGERS
|
||||
-- ============================================
|
||||
|
||||
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;
|
||||
|
||||
INSERT INTO public.user_subscriptions (user_id, plan_id)
|
||||
VALUES (new.id, (SELECT id FROM public.subscription_plans WHERE name = 'starter' LIMIT 1))
|
||||
ON CONFLICT (user_id) DO NOTHING;
|
||||
|
||||
INSERT INTO public.user_credits (user_id, balance)
|
||||
VALUES (new.id, 10)
|
||||
ON CONFLICT (user_id) DO NOTHING;
|
||||
|
||||
RETURN new;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql SECURITY DEFINER;
|
||||
|
||||
DROP TRIGGER IF EXISTS on_auth_user_created ON auth.users;
|
||||
CREATE TRIGGER on_auth_user_created
|
||||
AFTER INSERT ON auth.users
|
||||
FOR EACH ROW EXECUTE FUNCTION public.handle_new_user();
|
||||
|
||||
-- Helper Functions for RLS
|
||||
CREATE OR REPLACE FUNCTION public.check_is_split_host(check_split_id UUID, check_user_id UUID)
|
||||
RETURNS BOOLEAN AS $$
|
||||
BEGIN
|
||||
RETURN EXISTS (
|
||||
SELECT 1 FROM public.bottle_splits
|
||||
WHERE id = check_split_id AND host_id = check_user_id
|
||||
);
|
||||
END;
|
||||
$$ LANGUAGE plpgsql SECURITY DEFINER;
|
||||
|
||||
CREATE OR REPLACE FUNCTION public.check_is_split_participant(check_split_id UUID, check_user_id UUID)
|
||||
RETURNS BOOLEAN AS $$
|
||||
BEGIN
|
||||
RETURN EXISTS (
|
||||
SELECT 1 FROM public.split_participants
|
||||
WHERE split_id = check_split_id AND user_id = check_user_id
|
||||
);
|
||||
END;
|
||||
$$ LANGUAGE plpgsql SECURITY DEFINER;
|
||||
|
||||
-- ============================================
|
||||
-- 5. ROW LEVEL SECURITY (RLS)
|
||||
-- ============================================
|
||||
|
||||
-- Explicitly enable for all
|
||||
ALTER TABLE public.profiles ENABLE ROW LEVEL SECURITY;
|
||||
ALTER TABLE public.bottles ENABLE ROW LEVEL SECURITY;
|
||||
ALTER TABLE public.tastings ENABLE ROW LEVEL SECURITY;
|
||||
ALTER TABLE public.buddies ENABLE ROW LEVEL SECURITY;
|
||||
ALTER TABLE public.tasting_sessions ENABLE ROW LEVEL SECURITY;
|
||||
ALTER TABLE public.session_participants ENABLE ROW LEVEL SECURITY;
|
||||
ALTER TABLE public.tasting_tags ENABLE ROW LEVEL SECURITY;
|
||||
ALTER TABLE public.tasting_buddies ENABLE ROW LEVEL SECURITY;
|
||||
ALTER TABLE public.bottle_splits ENABLE ROW LEVEL SECURITY;
|
||||
ALTER TABLE public.split_participants ENABLE ROW LEVEL SECURITY;
|
||||
ALTER TABLE public.global_products ENABLE ROW LEVEL SECURITY;
|
||||
ALTER TABLE public.enrichment_cache ENABLE ROW LEVEL SECURITY;
|
||||
ALTER TABLE public.api_usage ENABLE ROW LEVEL SECURITY;
|
||||
ALTER TABLE public.user_credits ENABLE ROW LEVEL SECURITY;
|
||||
ALTER TABLE public.subscription_plans ENABLE ROW LEVEL SECURITY;
|
||||
ALTER TABLE public.user_subscriptions ENABLE ROW LEVEL SECURITY;
|
||||
ALTER TABLE public.admin_users ENABLE ROW LEVEL SECURITY;
|
||||
ALTER TABLE public.credit_transactions ENABLE ROW LEVEL SECURITY;
|
||||
ALTER TABLE public.buddy_invites ENABLE ROW LEVEL SECURITY;
|
||||
ALTER TABLE public.vision_cache ENABLE ROW LEVEL SECURITY;
|
||||
ALTER TABLE public.tags ENABLE ROW LEVEL SECURITY;
|
||||
|
||||
-- Policies
|
||||
CREATE POLICY "profiles_select_policy" ON public.profiles FOR SELECT USING (auth.uid() = id OR EXISTS (SELECT 1 FROM public.admin_users WHERE user_id = auth.uid()));
|
||||
CREATE POLICY "profiles_update_policy" ON public.profiles FOR UPDATE USING (auth.uid() = id OR EXISTS (SELECT 1 FROM public.admin_users WHERE user_id = auth.uid()));
|
||||
|
||||
CREATE POLICY "bottles_select_policy" ON public.bottles FOR SELECT USING (
|
||||
auth.uid() = user_id OR
|
||||
EXISTS (SELECT 1 FROM public.bottle_splits WHERE bottle_id = public.bottles.id AND is_active = true)
|
||||
);
|
||||
CREATE POLICY "bottles_insert_policy" ON public.bottles FOR INSERT WITH CHECK (auth.uid() = user_id);
|
||||
CREATE POLICY "bottles_update_policy" ON public.bottles FOR UPDATE USING (auth.uid() = user_id);
|
||||
CREATE POLICY "bottles_delete_policy" ON public.bottles FOR DELETE USING (auth.uid() = user_id);
|
||||
|
||||
CREATE POLICY "tastings_select_policy" ON public.tastings FOR SELECT USING (
|
||||
auth.uid() = user_id OR
|
||||
EXISTS (SELECT 1 FROM public.tasting_buddies tb JOIN public.buddies b ON b.id = tb.buddy_id WHERE tb.tasting_id = public.tastings.id AND b.buddy_profile_id = auth.uid())
|
||||
);
|
||||
CREATE POLICY "tastings_insert_policy" ON public.tastings FOR INSERT WITH CHECK (auth.uid() = user_id);
|
||||
CREATE POLICY "tastings_modify_policy" ON public.tastings FOR ALL USING (auth.uid() = user_id);
|
||||
|
||||
CREATE POLICY "tasting_buddies_all" ON public.tasting_buddies FOR ALL USING (auth.uid() = user_id);
|
||||
CREATE POLICY "tasting_tags_all" ON public.tasting_tags FOR ALL USING (auth.uid() = user_id);
|
||||
CREATE POLICY "session_participants_all" ON public.session_participants FOR ALL USING (auth.uid() = user_id);
|
||||
CREATE POLICY "sessions_access" ON public.tasting_sessions FOR ALL USING (auth.uid() = user_id OR id IN (SELECT session_id FROM public.session_participants WHERE buddy_id IN (SELECT id FROM public.buddies WHERE buddy_profile_id = auth.uid())));
|
||||
|
||||
CREATE POLICY "tags_select" ON public.tags FOR SELECT USING (is_system_default = true OR auth.uid() = created_by OR EXISTS (SELECT 1 FROM public.admin_users WHERE user_id = auth.uid()));
|
||||
CREATE POLICY "tags_insert" ON public.tags FOR INSERT WITH CHECK (auth.uid() = created_by);
|
||||
|
||||
CREATE POLICY "bottle_splits_host" ON public.bottle_splits FOR ALL USING (auth.uid() = host_id);
|
||||
CREATE POLICY "bottle_splits_view" ON public.bottle_splits FOR SELECT USING (is_active = true OR public.check_is_split_participant(id, auth.uid()));
|
||||
CREATE POLICY "split_participants_own" ON public.split_participants FOR ALL USING (auth.uid() = user_id);
|
||||
CREATE POLICY "split_participants_host" ON public.split_participants FOR ALL USING (public.check_is_split_host(split_id, auth.uid()));
|
||||
CREATE POLICY "split_participants_view" ON public.split_participants FOR SELECT USING (EXISTS (SELECT 1 FROM public.bottle_splits WHERE id = split_id AND is_active = true));
|
||||
|
||||
CREATE POLICY "global_products_select" ON public.global_products FOR SELECT USING (true);
|
||||
CREATE POLICY "global_products_admin" ON public.global_products FOR ALL USING (EXISTS (SELECT 1 FROM public.admin_users WHERE user_id = auth.uid()));
|
||||
CREATE POLICY "enrichment_cache_read_write" ON public.enrichment_cache FOR ALL TO authenticated USING (true);
|
||||
CREATE POLICY "vision_cache_select" ON public.vision_cache FOR SELECT TO authenticated USING (true);
|
||||
CREATE POLICY "api_usage_own" ON public.api_usage FOR SELECT USING (auth.uid() = user_id OR EXISTS (SELECT 1 FROM public.admin_users WHERE user_id = auth.uid()));
|
||||
CREATE POLICY "user_credits_own" ON public.user_credits FOR SELECT USING (auth.uid() = user_id OR EXISTS (SELECT 1 FROM public.admin_users WHERE user_id = auth.uid()));
|
||||
CREATE POLICY "admin_only_updates" ON public.user_credits FOR UPDATE USING (EXISTS (SELECT 1 FROM public.admin_users WHERE user_id = auth.uid()));
|
||||
CREATE POLICY "subscription_plans_public" ON public.subscription_plans FOR SELECT USING (is_active = true OR EXISTS (SELECT 1 FROM public.admin_users WHERE user_id = auth.uid()));
|
||||
CREATE POLICY "user_subscriptions_own" ON public.user_subscriptions FOR SELECT USING (auth.uid() = user_id OR EXISTS (SELECT 1 FROM public.admin_users WHERE user_id = auth.uid()));
|
||||
|
||||
-- ============================================
|
||||
-- 6. INDEXES
|
||||
-- ============================================
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_bottles_user_id ON public.bottles(user_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_buddies_user_id ON public.buddies(user_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_tastings_bottle_id ON public.tastings(bottle_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_tags_category_name ON public.tags(category, name);
|
||||
|
||||
-- ============================================
|
||||
-- 7. INITIAL DATA
|
||||
-- ============================================
|
||||
|
||||
INSERT INTO public.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;
|
||||
|
||||
-- ============================================
|
||||
-- Buddy Invites (Handshake Codes)
|
||||
-- ============================================
|
||||
|
||||
CREATE TABLE IF NOT EXISTS buddy_invites (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
creator_id UUID REFERENCES profiles(id) ON DELETE CASCADE NOT NULL,
|
||||
code TEXT NOT NULL UNIQUE, -- 6 char uppercase alphanumeric
|
||||
expires_at TIMESTAMP WITH TIME ZONE NOT NULL,
|
||||
created_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('Europe/Berlin'::text, now())
|
||||
);
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_buddy_invites_code ON buddy_invites(code);
|
||||
CREATE INDEX IF NOT EXISTS idx_buddy_invites_creator_id ON buddy_invites(creator_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_buddy_invites_expires_at ON buddy_invites(expires_at);
|
||||
|
||||
ALTER TABLE buddy_invites ENABLE ROW LEVEL SECURITY;
|
||||
|
||||
-- Only creator can see their own invites
|
||||
DROP POLICY IF EXISTS "buddy_invites_creator_policy" ON buddy_invites;
|
||||
CREATE POLICY "buddy_invites_creator_policy" ON buddy_invites
|
||||
FOR ALL USING ((SELECT auth.uid()) = creator_id);
|
||||
|
||||
-- Allow anyone to SELECT by code (needed for redemption) but only if not expired
|
||||
DROP POLICY IF EXISTS "buddy_invites_redeem_policy" ON buddy_invites;
|
||||
CREATE POLICY "buddy_invites_redeem_policy" ON buddy_invites
|
||||
FOR SELECT USING (expires_at > now());
|
||||
|
||||
-- ============================================
|
||||
-- Bottle Splits (Flaschenteilung)
|
||||
-- ============================================
|
||||
|
||||
CREATE TABLE IF NOT EXISTS bottle_splits (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
bottle_id UUID REFERENCES bottles(id) ON DELETE CASCADE UNIQUE,
|
||||
host_id UUID REFERENCES profiles(id) ON DELETE CASCADE NOT NULL,
|
||||
total_volume INTEGER DEFAULT 70, -- in cl
|
||||
host_share INTEGER DEFAULT 10, -- what the host keeps, in cl
|
||||
price_bottle DECIMAL(10, 2) NOT NULL,
|
||||
sample_sizes JSONB DEFAULT '[{"cl": 5, "glass_cost": 0.80}, {"cl": 10, "glass_cost": 1.50}]'::jsonb,
|
||||
shipping_options JSONB DEFAULT '[]'::jsonb,
|
||||
is_active BOOLEAN DEFAULT true,
|
||||
public_slug TEXT UNIQUE NOT NULL,
|
||||
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 IF NOT EXISTS idx_bottle_splits_host_id ON bottle_splits(host_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_bottle_splits_public_slug ON bottle_splits(public_slug);
|
||||
CREATE INDEX IF NOT EXISTS idx_bottle_splits_bottle_id ON bottle_splits(bottle_id);
|
||||
|
||||
ALTER TABLE bottle_splits ENABLE ROW LEVEL SECURITY;
|
||||
|
||||
-- Host can manage their own splits
|
||||
DROP POLICY IF EXISTS "bottle_splits_host_policy" ON bottle_splits;
|
||||
CREATE POLICY "bottle_splits_host_policy" ON bottle_splits
|
||||
FOR ALL USING ((SELECT auth.uid()) = host_id);
|
||||
|
||||
-- Anyone can view active splits (for public page)
|
||||
DROP POLICY IF EXISTS "bottle_splits_public_view" ON bottle_splits;
|
||||
CREATE POLICY "bottle_splits_public_view" ON bottle_splits
|
||||
FOR SELECT USING (is_active = true);
|
||||
|
||||
-- Split Participants
|
||||
CREATE TABLE IF NOT EXISTS split_participants (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
split_id UUID REFERENCES bottle_splits(id) ON DELETE CASCADE NOT NULL,
|
||||
user_id UUID REFERENCES profiles(id) ON DELETE CASCADE NOT NULL,
|
||||
amount_cl INTEGER NOT NULL CHECK (amount_cl > 0),
|
||||
shipping_method TEXT NOT NULL,
|
||||
total_cost DECIMAL(10, 2) NOT NULL,
|
||||
status TEXT DEFAULT 'PENDING' CHECK (status IN ('PENDING', 'APPROVED', 'PAID', 'SHIPPED', 'REJECTED', 'WAITLIST')),
|
||||
created_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('Europe/Berlin'::text, now()),
|
||||
UNIQUE(split_id, user_id)
|
||||
);
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_split_participants_split_id ON split_participants(split_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_split_participants_user_id ON split_participants(user_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_split_participants_status ON split_participants(status);
|
||||
|
||||
ALTER TABLE split_participants ENABLE ROW LEVEL SECURITY;
|
||||
|
||||
-- Users can view their own participations
|
||||
DROP POLICY IF EXISTS "split_participants_own_policy" ON split_participants;
|
||||
CREATE POLICY "split_participants_own_policy" ON split_participants
|
||||
FOR ALL USING ((SELECT auth.uid()) = user_id);
|
||||
|
||||
-- Hosts can view/manage participants for their splits
|
||||
DROP POLICY IF EXISTS "split_participants_host_policy" ON split_participants;
|
||||
CREATE POLICY "split_participants_host_policy" ON split_participants
|
||||
FOR ALL USING (
|
||||
split_id IN (SELECT id FROM bottle_splits WHERE host_id = (SELECT auth.uid()))
|
||||
);
|
||||
|
||||
-- Anyone can view participants for public splits (to show fill-level)
|
||||
DROP POLICY IF EXISTS "split_participants_public_view" ON split_participants;
|
||||
CREATE POLICY "split_participants_public_view" ON split_participants
|
||||
FOR SELECT USING (
|
||||
split_id IN (SELECT id FROM bottle_splits WHERE is_active = true)
|
||||
);
|
||||
|
||||
Reference in New Issue
Block a user