-- Initial database setup for PostgreSQL -- Migration: 001_initial_setup -- Database: PostgreSQL -- Enable UUID extension CREATE EXTENSION IF NOT EXISTS "uuid-ossp"; -- Users table for authentication CREATE TABLE IF NOT EXISTS users ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), username VARCHAR(255) NOT NULL UNIQUE, email VARCHAR(255) NOT NULL UNIQUE, password_hash VARCHAR(255) NOT NULL, is_active BOOLEAN NOT NULL DEFAULT true, is_verified BOOLEAN NOT NULL DEFAULT false, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW() ); -- User sessions table CREATE TABLE IF NOT EXISTS user_sessions ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE, session_token VARCHAR(255) NOT NULL UNIQUE, expires_at TIMESTAMPTZ NOT NULL, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW() ); -- Content table for CMS functionality CREATE TABLE IF NOT EXISTS content ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), title VARCHAR(255) NOT NULL, slug VARCHAR(255) NOT NULL UNIQUE, content_type VARCHAR(50) NOT NULL DEFAULT 'markdown', body TEXT, metadata JSONB, is_published BOOLEAN NOT NULL DEFAULT false, published_at TIMESTAMPTZ, created_by UUID REFERENCES users(id), created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW() ); -- User roles table CREATE TABLE IF NOT EXISTS user_roles ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), name VARCHAR(100) NOT NULL UNIQUE, description TEXT, permissions JSONB, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW() ); -- User role assignments CREATE TABLE IF NOT EXISTS user_role_assignments ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE, role_id UUID NOT NULL REFERENCES user_roles(id) ON DELETE CASCADE, assigned_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), assigned_by UUID REFERENCES users(id), UNIQUE(user_id, role_id) ); -- Create indexes for better performance CREATE INDEX IF NOT EXISTS idx_users_email ON users(email); CREATE INDEX IF NOT EXISTS idx_users_username ON users(username); CREATE INDEX IF NOT EXISTS idx_users_active ON users(is_active); CREATE INDEX IF NOT EXISTS idx_user_sessions_token ON user_sessions(session_token); CREATE INDEX IF NOT EXISTS idx_user_sessions_user_id ON user_sessions(user_id); CREATE INDEX IF NOT EXISTS idx_user_sessions_expires ON user_sessions(expires_at); CREATE INDEX IF NOT EXISTS idx_content_slug ON content(slug); CREATE INDEX IF NOT EXISTS idx_content_published ON content(is_published); CREATE INDEX IF NOT EXISTS idx_content_created_by ON content(created_by); CREATE INDEX IF NOT EXISTS idx_content_type ON content(content_type); CREATE INDEX IF NOT EXISTS idx_user_role_assignments_user ON user_role_assignments(user_id); CREATE INDEX IF NOT EXISTS idx_user_role_assignments_role ON user_role_assignments(role_id); -- Update timestamp trigger function CREATE OR REPLACE FUNCTION update_updated_at_column() RETURNS TRIGGER AS $$ BEGIN NEW.updated_at = NOW(); RETURN NEW; END; $$ language 'plpgsql'; -- Apply triggers to tables with updated_at columns CREATE TRIGGER update_users_updated_at BEFORE UPDATE ON users FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); CREATE TRIGGER update_content_updated_at BEFORE UPDATE ON content FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); -- Insert default roles INSERT INTO user_roles (name, description, permissions) VALUES ('admin', 'Administrator with full access', '{"all": true}'), ('editor', 'Content editor', '{"content": {"read": true, "write": true, "delete": true}}'), ('user', 'Regular user', '{"content": {"read": true}}') ON CONFLICT (name) DO NOTHING;