feat: [US-003] - Supabase schema for users and projects
Co-Authored-By: Claude Opus 4.5 <noreply@anthropic.com>
This commit is contained in:
parent
0440d632cd
commit
29688a61b9
|
|
@ -0,0 +1,114 @@
|
|||
-- Migration: Create profiles and projects tables with RLS policies
|
||||
-- Created for WebVNWrite - Visual Novel Flowchart Editor
|
||||
|
||||
-- Enable UUID extension if not already enabled
|
||||
CREATE EXTENSION IF NOT EXISTS "uuid-ossp";
|
||||
|
||||
-- =============================================================================
|
||||
-- PROFILES TABLE
|
||||
-- =============================================================================
|
||||
-- Stores user profile information linked to auth.users
|
||||
CREATE TABLE IF NOT EXISTS profiles (
|
||||
id uuid PRIMARY KEY REFERENCES auth.users(id) ON DELETE CASCADE,
|
||||
email text NOT NULL,
|
||||
display_name text,
|
||||
is_admin boolean DEFAULT false,
|
||||
created_at timestamptz DEFAULT now()
|
||||
);
|
||||
|
||||
-- Enable Row Level Security on profiles
|
||||
ALTER TABLE profiles ENABLE ROW LEVEL SECURITY;
|
||||
|
||||
-- RLS Policy: Users can SELECT their own profile
|
||||
CREATE POLICY "Users can view own profile"
|
||||
ON profiles
|
||||
FOR SELECT
|
||||
USING (auth.uid() = id);
|
||||
|
||||
-- RLS Policy: Admin users can SELECT all profiles
|
||||
CREATE POLICY "Admins can view all profiles"
|
||||
ON profiles
|
||||
FOR SELECT
|
||||
USING (
|
||||
EXISTS (
|
||||
SELECT 1 FROM profiles
|
||||
WHERE profiles.id = auth.uid()
|
||||
AND profiles.is_admin = true
|
||||
)
|
||||
);
|
||||
|
||||
-- RLS Policy: Users can UPDATE their own profile (for display_name changes)
|
||||
CREATE POLICY "Users can update own profile"
|
||||
ON profiles
|
||||
FOR UPDATE
|
||||
USING (auth.uid() = id)
|
||||
WITH CHECK (auth.uid() = id);
|
||||
|
||||
-- RLS Policy: Allow INSERT for authenticated users (needed for signup flow)
|
||||
CREATE POLICY "Users can insert own profile"
|
||||
ON profiles
|
||||
FOR INSERT
|
||||
WITH CHECK (auth.uid() = id);
|
||||
|
||||
-- =============================================================================
|
||||
-- PROJECTS TABLE
|
||||
-- =============================================================================
|
||||
-- Stores visual novel projects with flowchart data as JSONB
|
||||
CREATE TABLE IF NOT EXISTS projects (
|
||||
id uuid PRIMARY KEY DEFAULT uuid_generate_v4(),
|
||||
user_id uuid NOT NULL REFERENCES profiles(id) ON DELETE CASCADE,
|
||||
name text NOT NULL,
|
||||
flowchart_data jsonb DEFAULT '{"nodes": [], "edges": []}'::jsonb,
|
||||
created_at timestamptz DEFAULT now(),
|
||||
updated_at timestamptz DEFAULT now()
|
||||
);
|
||||
|
||||
-- Enable Row Level Security on projects
|
||||
ALTER TABLE projects ENABLE ROW LEVEL SECURITY;
|
||||
|
||||
-- RLS Policy: Users can SELECT their own projects
|
||||
CREATE POLICY "Users can view own projects"
|
||||
ON projects
|
||||
FOR SELECT
|
||||
USING (auth.uid() = user_id);
|
||||
|
||||
-- RLS Policy: Users can INSERT their own projects
|
||||
CREATE POLICY "Users can create own projects"
|
||||
ON projects
|
||||
FOR INSERT
|
||||
WITH CHECK (auth.uid() = user_id);
|
||||
|
||||
-- RLS Policy: Users can UPDATE their own projects
|
||||
CREATE POLICY "Users can update own projects"
|
||||
ON projects
|
||||
FOR UPDATE
|
||||
USING (auth.uid() = user_id)
|
||||
WITH CHECK (auth.uid() = user_id);
|
||||
|
||||
-- RLS Policy: Users can DELETE their own projects
|
||||
CREATE POLICY "Users can delete own projects"
|
||||
ON projects
|
||||
FOR DELETE
|
||||
USING (auth.uid() = user_id);
|
||||
|
||||
-- =============================================================================
|
||||
-- INDEXES
|
||||
-- =============================================================================
|
||||
-- Index for faster project lookups by user
|
||||
CREATE INDEX IF NOT EXISTS idx_projects_user_id ON projects(user_id);
|
||||
|
||||
-- =============================================================================
|
||||
-- TRIGGER: Auto-update updated_at timestamp
|
||||
-- =============================================================================
|
||||
CREATE OR REPLACE FUNCTION update_updated_at_column()
|
||||
RETURNS TRIGGER AS $$
|
||||
BEGIN
|
||||
NEW.updated_at = now();
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$ language 'plpgsql';
|
||||
|
||||
CREATE TRIGGER update_projects_updated_at
|
||||
BEFORE UPDATE ON projects
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION update_updated_at_column();
|
||||
Loading…
Reference in New Issue