-- Migration 001: Initial Database Setup -- This migration creates all necessary tables for authentication and content management -- Enable UUID extension CREATE EXTENSION IF NOT EXISTS "uuid-ossp"; -- Users table - core user information CREATE TABLE users ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), email VARCHAR(255) UNIQUE NOT NULL, username VARCHAR(50) UNIQUE NOT NULL, password_hash VARCHAR(255), display_name VARCHAR(100), avatar_url TEXT, is_active BOOLEAN DEFAULT TRUE, email_verified BOOLEAN DEFAULT FALSE, created_at TIMESTAMPTZ DEFAULT NOW(), updated_at TIMESTAMPTZ DEFAULT NOW(), last_login TIMESTAMPTZ, -- Profile information first_name VARCHAR(100), last_name VARCHAR(100), bio TEXT, timezone VARCHAR(50), locale VARCHAR(10), preferences JSONB DEFAULT '{}'::jsonb, -- Constraints CONSTRAINT users_email_format CHECK (email ~* '^[A-Za-z0-9._%+-]+@[A-Za-z0-9.-]+\.[A-Za-z]{2,}$'), CONSTRAINT users_username_format CHECK (username ~* '^[A-Za-z0-9_-]{3,50}$'), CONSTRAINT users_display_name_length CHECK (char_length(display_name) >= 1) ); -- User roles table - RBAC implementation CREATE TABLE user_roles ( user_id UUID REFERENCES users(id) ON DELETE CASCADE, role VARCHAR(50) NOT NULL, created_at TIMESTAMPTZ DEFAULT NOW(), PRIMARY KEY (user_id, role), -- Constraints CONSTRAINT user_roles_valid_role CHECK (role IN ('admin', 'moderator', 'user', 'guest') OR role LIKE 'custom_%') ); -- OAuth accounts table - external authentication providers CREATE TABLE oauth_accounts ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), user_id UUID REFERENCES users(id) ON DELETE CASCADE, provider VARCHAR(50) NOT NULL, provider_id VARCHAR(255) NOT NULL, provider_email VARCHAR(255) NOT NULL, provider_data JSONB NOT NULL, created_at TIMESTAMPTZ DEFAULT NOW(), updated_at TIMESTAMPTZ DEFAULT NOW(), -- Constraints UNIQUE(provider, provider_id), CONSTRAINT oauth_accounts_valid_provider CHECK (provider IN ('google', 'github', 'discord', 'microsoft') OR provider LIKE 'custom_%') ); -- Sessions table - session management CREATE TABLE sessions ( id VARCHAR(255) PRIMARY KEY, user_id UUID REFERENCES users(id) ON DELETE CASCADE, created_at TIMESTAMPTZ DEFAULT NOW(), expires_at TIMESTAMPTZ NOT NULL, last_accessed TIMESTAMPTZ DEFAULT NOW(), ip_address INET, user_agent TEXT, is_active BOOLEAN DEFAULT TRUE, -- Constraints CONSTRAINT sessions_valid_expiry CHECK (expires_at > created_at) ); -- Tokens table - password reset, email verification, etc. CREATE TABLE tokens ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), user_id UUID REFERENCES users(id) ON DELETE CASCADE, token_type VARCHAR(50) NOT NULL, token_hash VARCHAR(255) NOT NULL, expires_at TIMESTAMPTZ NOT NULL, created_at TIMESTAMPTZ DEFAULT NOW(), used_at TIMESTAMPTZ, is_active BOOLEAN DEFAULT TRUE, -- Constraints CONSTRAINT tokens_valid_type CHECK (token_type IN ('password_reset', 'email_verification', 'account_activation')), CONSTRAINT tokens_valid_expiry CHECK (expires_at > created_at), CONSTRAINT tokens_used_logic CHECK (used_at IS NULL OR used_at >= created_at) ); -- Permissions table - for fine-grained access control CREATE TABLE permissions ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), name VARCHAR(100) UNIQUE NOT NULL, description TEXT, resource VARCHAR(100) NOT NULL, action VARCHAR(100) NOT NULL, created_at TIMESTAMPTZ DEFAULT NOW(), -- Constraints CONSTRAINT permissions_name_format CHECK (name ~* '^[a-z][a-z0-9_]*[a-z0-9]$'), CONSTRAINT permissions_resource_format CHECK (resource ~* '^[a-z][a-z0-9_]*[a-z0-9]$'), CONSTRAINT permissions_action_format CHECK (action IN ('create', 'read', 'update', 'delete', 'manage', 'execute')) ); -- Role permissions table - many-to-many relationship CREATE TABLE role_permissions ( role VARCHAR(50) NOT NULL, permission_id UUID REFERENCES permissions(id) ON DELETE CASCADE, created_at TIMESTAMPTZ DEFAULT NOW(), PRIMARY KEY (role, permission_id), -- Constraints CONSTRAINT role_permissions_valid_role CHECK (role IN ('admin', 'moderator', 'user', 'guest') OR role LIKE 'custom_%') ); -- User audit log - track important user actions CREATE TABLE user_audit_log ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), user_id UUID REFERENCES users(id) ON DELETE SET NULL, action VARCHAR(100) NOT NULL, resource VARCHAR(100), resource_id UUID, old_values JSONB, new_values JSONB, ip_address INET, user_agent TEXT, created_at TIMESTAMPTZ DEFAULT NOW(), -- Constraints CONSTRAINT audit_log_valid_action CHECK (action IN ('login', 'logout', 'register', 'update_profile', 'change_password', 'oauth_login', 'password_reset', 'email_verify')) ); -- Page contents table - main content management CREATE TABLE page_contents ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), slug VARCHAR(255) NOT NULL UNIQUE, title VARCHAR(500) NOT NULL, name VARCHAR(255) NOT NULL, author VARCHAR(255), author_id UUID, content_type VARCHAR(50) NOT NULL DEFAULT 'page', content_format VARCHAR(20) NOT NULL DEFAULT 'markdown', content TEXT NOT NULL, container VARCHAR(255) NOT NULL DEFAULT 'page-container', state VARCHAR(20) NOT NULL DEFAULT 'draft', require_login BOOLEAN NOT NULL DEFAULT FALSE, date_init TIMESTAMPTZ NOT NULL DEFAULT NOW(), date_end TIMESTAMPTZ, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), published_at TIMESTAMPTZ, metadata JSONB DEFAULT '{}', tags TEXT[] DEFAULT '{}', category VARCHAR(255), featured_image VARCHAR(500), excerpt TEXT, seo_title VARCHAR(500), seo_description TEXT, allow_comments BOOLEAN NOT NULL DEFAULT TRUE, view_count BIGINT NOT NULL DEFAULT 0, sort_order INTEGER NOT NULL DEFAULT 0, CONSTRAINT fk_author FOREIGN KEY (author_id) REFERENCES users(id) ON DELETE SET NULL ); -- Indexes for users table CREATE INDEX idx_users_email ON users(email); CREATE INDEX idx_users_username ON users(username); CREATE INDEX idx_users_is_active ON users(is_active); CREATE INDEX idx_users_created_at ON users(created_at); CREATE INDEX idx_users_email_verified ON users(email_verified); -- Indexes for user_roles table CREATE INDEX idx_user_roles_user_id ON user_roles(user_id); CREATE INDEX idx_user_roles_role ON user_roles(role); -- Indexes for oauth_accounts table CREATE INDEX idx_oauth_accounts_user_id ON oauth_accounts(user_id); CREATE INDEX idx_oauth_accounts_provider ON oauth_accounts(provider, provider_id); CREATE INDEX idx_oauth_accounts_provider_email ON oauth_accounts(provider_email); -- Indexes for sessions table CREATE INDEX idx_sessions_user_id ON sessions(user_id); CREATE INDEX idx_sessions_expires_at ON sessions(expires_at); CREATE INDEX idx_sessions_is_active ON sessions(is_active); CREATE INDEX idx_sessions_last_accessed ON sessions(last_accessed); -- Indexes for tokens table CREATE INDEX idx_tokens_user_id ON tokens(user_id); CREATE INDEX idx_tokens_type ON tokens(token_type); CREATE INDEX idx_tokens_expires_at ON tokens(expires_at); CREATE INDEX idx_tokens_is_active ON tokens(is_active); CREATE INDEX idx_tokens_hash ON tokens(token_hash); -- Indexes for permissions table CREATE INDEX idx_permissions_name ON permissions(name); CREATE INDEX idx_permissions_resource ON permissions(resource); CREATE INDEX idx_permissions_action ON permissions(action); -- Indexes for role_permissions table CREATE INDEX idx_role_permissions_role ON role_permissions(role); CREATE INDEX idx_role_permissions_permission ON role_permissions(permission_id); -- Indexes for user_audit_log table CREATE INDEX idx_user_audit_log_user_id ON user_audit_log(user_id); CREATE INDEX idx_user_audit_log_action ON user_audit_log(action); CREATE INDEX idx_user_audit_log_created_at ON user_audit_log(created_at); -- Indexes for page_contents table CREATE INDEX idx_page_contents_slug ON page_contents(slug); CREATE INDEX idx_page_contents_state ON page_contents(state); CREATE INDEX idx_page_contents_content_type ON page_contents(content_type); CREATE INDEX idx_page_contents_author_id ON page_contents(author_id); CREATE INDEX idx_page_contents_category ON page_contents(category); CREATE INDEX idx_page_contents_tags ON page_contents USING GIN(tags); CREATE INDEX idx_page_contents_published_at ON page_contents(published_at); CREATE INDEX idx_page_contents_created_at ON page_contents(created_at); CREATE INDEX idx_page_contents_view_count ON page_contents(view_count); CREATE INDEX idx_page_contents_sort_order ON page_contents(sort_order); CREATE INDEX idx_page_contents_metadata ON page_contents USING GIN(metadata); -- Full-text search index for page_contents CREATE INDEX idx_page_contents_search ON page_contents USING GIN( to_tsvector('english', title || ' ' || COALESCE(content, '') || ' ' || COALESCE(excerpt, '')) ); -- Partial indexes for published content CREATE INDEX idx_page_contents_published_public ON page_contents(created_at DESC) WHERE state = 'published' AND require_login = FALSE; CREATE INDEX idx_page_contents_published_by_type ON page_contents(content_type, created_at DESC) WHERE state = 'published'; -- Function to 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'; -- Triggers to automatically update updated_at CREATE TRIGGER update_users_updated_at BEFORE UPDATE ON users FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); CREATE TRIGGER update_oauth_accounts_updated_at BEFORE UPDATE ON oauth_accounts FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); CREATE TRIGGER update_page_contents_updated_at BEFORE UPDATE ON page_contents FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); -- Function to automatically assign default role to new users CREATE OR REPLACE FUNCTION assign_default_role() RETURNS TRIGGER AS $$ BEGIN INSERT INTO user_roles (user_id, role) VALUES (NEW.id, 'user'); RETURN NEW; END; $$ language 'plpgsql'; -- Trigger to assign default role CREATE TRIGGER assign_default_role_trigger AFTER INSERT ON users FOR EACH ROW EXECUTE FUNCTION assign_default_role(); -- Function to log user actions CREATE OR REPLACE FUNCTION log_user_action( p_user_id UUID, p_action VARCHAR(100), p_resource VARCHAR(100) DEFAULT NULL, p_resource_id UUID DEFAULT NULL, p_old_values JSONB DEFAULT NULL, p_new_values JSONB DEFAULT NULL, p_ip_address INET DEFAULT NULL, p_user_agent TEXT DEFAULT NULL ) RETURNS UUID AS $$ DECLARE log_id UUID; BEGIN INSERT INTO user_audit_log ( user_id, action, resource, resource_id, old_values, new_values, ip_address, user_agent ) VALUES ( p_user_id, p_action, p_resource, p_resource_id, p_old_values, p_new_values, p_ip_address, p_user_agent ) RETURNING id INTO log_id; RETURN log_id; END; $$ LANGUAGE plpgsql; -- Function to clean up expired sessions and tokens CREATE OR REPLACE FUNCTION cleanup_expired_auth_data() RETURNS INTEGER AS $$ DECLARE deleted_count INTEGER := 0; temp_count INTEGER; BEGIN -- Delete expired sessions DELETE FROM sessions WHERE expires_at < NOW(); GET DIAGNOSTICS temp_count = ROW_COUNT; deleted_count := deleted_count + temp_count; -- Delete expired tokens DELETE FROM tokens WHERE expires_at < NOW(); GET DIAGNOSTICS temp_count = ROW_COUNT; deleted_count := deleted_count + temp_count; -- Delete old audit logs (older than 1 year) DELETE FROM user_audit_log WHERE created_at < NOW() - INTERVAL '1 year'; GET DIAGNOSTICS temp_count = ROW_COUNT; deleted_count := deleted_count + temp_count; RETURN deleted_count; END; $$ LANGUAGE plpgsql; -- Default permissions INSERT INTO permissions (name, description, resource, action) VALUES ('read_users', 'Read user information', 'users', 'read'), ('write_users', 'Create and update users', 'users', 'create'), ('delete_users', 'Delete users', 'users', 'delete'), ('manage_users', 'Full user management', 'users', 'manage'), ('read_content', 'Read content', 'content', 'read'), ('write_content', 'Create and update content', 'content', 'create'), ('delete_content', 'Delete content', 'content', 'delete'), ('manage_content', 'Full content management', 'content', 'manage'), ('manage_roles', 'Manage user roles and permissions', 'roles', 'manage'), ('manage_system', 'System administration', 'system', 'manage'), ('read_audit_log', 'Read audit logs', 'audit_log', 'read'), ('execute_maintenance', 'Execute maintenance tasks', 'system', 'execute'); -- Default role permissions INSERT INTO role_permissions (role, permission_id) SELECT 'admin', id FROM permissions; INSERT INTO role_permissions (role, permission_id) SELECT 'moderator', id FROM permissions WHERE name IN ('read_users', 'read_content', 'write_content', 'delete_content', 'read_audit_log'); INSERT INTO role_permissions (role, permission_id) SELECT 'user', id FROM permissions WHERE name IN ('read_content', 'write_content'); INSERT INTO role_permissions (role, permission_id) SELECT 'guest', id FROM permissions WHERE name IN ('read_content'); -- Create a default admin user (password: 'admin123' - change this!) -- Password hash for 'admin123' with Argon2 INSERT INTO users (email, username, password_hash, display_name, email_verified, is_active) VALUES ( 'admin@example.com', 'admin', '$argon2id$v=19$m=19456,t=2,p=1$4K5FCBeajDVi8smeWgce3w$y9zZkuvLE3H3GwTFgfl/ngjqlnjiuDRIPiBqu0yFICA', 'System Administrator', TRUE, TRUE ); -- Assign admin role to the default admin user INSERT INTO user_roles (user_id, role) SELECT id, 'admin' FROM users WHERE username = 'admin'; -- Sample page content data INSERT INTO page_contents ( slug, title, name, content_type, content, container, state, require_login, tags, category, excerpt, allow_comments ) VALUES ( 'welcome', 'Welcome to Our Site', 'welcome-page', 'page', '# Welcome to Our Site Welcome to our amazing website! This is a sample page to demonstrate our content management system. ## Features - Dynamic content loading - Markdown support - SEO optimization - Multi-format content support Feel free to explore and discover what we have to offer.', 'page-container', 'published', false, ARRAY['welcome', 'introduction'], 'general', 'Welcome to our amazing website! This is a sample page to demonstrate our content management system.', false ), ( 'about', 'About Us', 'about-page', 'page', '# About Us We are a team of passionate developers creating amazing web experiences. ## Our Mission To build innovative solutions that make the web a better place. ## Our Values - Quality - Innovation - User Experience - Open Source', 'page-container', 'published', false, ARRAY['about', 'company'], 'general', 'We are a team of passionate developers creating amazing web experiences.', false ), ( 'sample-blog-post', 'Getting Started with Rust and Web Development', 'sample-blog', 'blog', '# Getting Started with Rust and Web Development Rust is becoming increasingly popular for web development, and for good reason! ## Why Rust for Web Development? 1. **Performance**: Rust offers near C++ performance 2. **Safety**: Memory safety without garbage collection 3. **Concurrency**: Excellent support for concurrent programming 4. **Ecosystem**: Growing ecosystem of web frameworks ## Popular Rust Web Frameworks - **Axum**: A modern, async web framework - **Warp**: A super-easy, composable, web server framework - **Actix-web**: A powerful, pragmatic, and extremely fast web framework ## Getting Started ```rust use axum::{response::Html, routing::get, Router}; #[tokio::main] async fn main() { let app = Router::new().route("/", get(|| async { Html("