131 lines
3.2 KiB
SQL
131 lines
3.2 KiB
SQL
/*
|
|
# Initial schema setup for CampFire Critics
|
|
|
|
1. New Tables
|
|
- `users`
|
|
- `id` (uuid, primary key)
|
|
- `email` (text, unique)
|
|
- `username` (text, unique)
|
|
- `role` (text)
|
|
- `created_at` (timestamp)
|
|
- `profile_picture` (text)
|
|
- `bio` (text)
|
|
- `is_critic` (boolean)
|
|
|
|
- `media`
|
|
- `id` (uuid, primary key)
|
|
- `title` (text)
|
|
- `type` (text)
|
|
- `poster_url` (text)
|
|
- `backdrop_url` (text)
|
|
- `overview` (text)
|
|
- `release_date` (date)
|
|
- `created_at` (timestamp)
|
|
- `created_by` (uuid, references users)
|
|
- `is_published` (boolean)
|
|
|
|
- `reviews`
|
|
- `id` (uuid, primary key)
|
|
- `user_id` (uuid, references users)
|
|
- `media_id` (uuid, references media)
|
|
- `content` (text)
|
|
- `ratings` (jsonb)
|
|
- `created_at` (timestamp)
|
|
- `has_spoilers` (boolean)
|
|
|
|
2. Security
|
|
- Enable RLS on all tables
|
|
- Add policies for authenticated users
|
|
- Add special policies for admin/moderator roles
|
|
*/
|
|
|
|
-- Create users table
|
|
CREATE TABLE IF NOT EXISTS users (
|
|
id uuid PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
email text UNIQUE NOT NULL,
|
|
username text UNIQUE NOT NULL,
|
|
role text NOT NULL DEFAULT 'user',
|
|
created_at timestamptz DEFAULT now(),
|
|
profile_picture text,
|
|
bio text,
|
|
is_critic boolean DEFAULT false
|
|
);
|
|
|
|
-- Create media table
|
|
CREATE TABLE IF NOT EXISTS media (
|
|
id uuid PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
title text NOT NULL,
|
|
type text NOT NULL,
|
|
poster_url text,
|
|
backdrop_url text,
|
|
overview text,
|
|
release_date date,
|
|
created_at timestamptz DEFAULT now(),
|
|
created_by uuid REFERENCES users(id),
|
|
is_published boolean DEFAULT false
|
|
);
|
|
|
|
-- Create reviews table
|
|
CREATE TABLE IF NOT EXISTS reviews (
|
|
id uuid PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
user_id uuid REFERENCES users(id),
|
|
media_id uuid REFERENCES media(id),
|
|
content text NOT NULL,
|
|
ratings jsonb NOT NULL,
|
|
created_at timestamptz DEFAULT now(),
|
|
has_spoilers boolean DEFAULT false
|
|
);
|
|
|
|
-- Enable RLS
|
|
ALTER TABLE users ENABLE ROW LEVEL SECURITY;
|
|
ALTER TABLE media ENABLE ROW LEVEL SECURITY;
|
|
ALTER TABLE reviews ENABLE ROW LEVEL SECURITY;
|
|
|
|
-- Users policies
|
|
CREATE POLICY "Users can read all users"
|
|
ON users FOR SELECT
|
|
TO authenticated
|
|
USING (true);
|
|
|
|
CREATE POLICY "Users can update own profile"
|
|
ON users FOR UPDATE
|
|
TO authenticated
|
|
USING (auth.uid() = id);
|
|
|
|
-- Media policies
|
|
CREATE POLICY "Anyone can read published media"
|
|
ON media FOR SELECT
|
|
TO authenticated
|
|
USING (is_published = true);
|
|
|
|
CREATE POLICY "Admins and moderators can manage all media"
|
|
ON media FOR ALL
|
|
TO authenticated
|
|
USING (
|
|
EXISTS (
|
|
SELECT 1 FROM users
|
|
WHERE id = auth.uid()
|
|
AND role IN ('admin', 'moderator')
|
|
)
|
|
);
|
|
|
|
-- Reviews policies
|
|
CREATE POLICY "Anyone can read reviews"
|
|
ON reviews FOR SELECT
|
|
TO authenticated
|
|
USING (true);
|
|
|
|
CREATE POLICY "Users can create reviews"
|
|
ON reviews FOR INSERT
|
|
TO authenticated
|
|
WITH CHECK (auth.uid() = user_id);
|
|
|
|
CREATE POLICY "Users can update own reviews"
|
|
ON reviews FOR UPDATE
|
|
TO authenticated
|
|
USING (auth.uid() = user_id);
|
|
|
|
CREATE POLICY "Users can delete own reviews"
|
|
ON reviews FOR DELETE
|
|
TO authenticated
|
|
USING (auth.uid() = user_id); |