-- PostgreSQL initialization script for my-uploader-bot (LOCAL VERSION - NO SSL) -- This script sets up the database, users, and extensions for local development -- Create database if it doesn't exist SELECT 'CREATE DATABASE myuploader' WHERE NOT EXISTS (SELECT FROM pg_database WHERE datname = 'myuploader')\gexec -- Connect to the database \c myuploader; -- Create extensions CREATE EXTENSION IF NOT EXISTS "uuid-ossp"; CREATE EXTENSION IF NOT EXISTS "pg_trgm"; CREATE EXTENSION IF NOT EXISTS "btree_gin"; CREATE EXTENSION IF NOT EXISTS "pgcrypto"; -- Create custom types DO $$ BEGIN CREATE TYPE user_role_type AS ENUM ('admin', 'user', 'moderator'); EXCEPTION WHEN duplicate_object THEN null; END $$; DO $$ BEGIN CREATE TYPE content_status_type AS ENUM ('pending', 'uploading', 'processing', 'completed', 'failed', 'deleted'); EXCEPTION WHEN duplicate_object THEN null; END $$; DO $$ BEGIN CREATE TYPE transaction_status_type AS ENUM ('pending', 'confirmed', 'failed', 'cancelled'); EXCEPTION WHEN duplicate_object THEN null; END $$; -- Create application user (for connection pooling) DO $$ BEGIN CREATE USER app_user WITH PASSWORD 'secure_app_password'; EXCEPTION WHEN duplicate_object THEN ALTER USER app_user WITH PASSWORD 'secure_app_password'; END $$; -- Grant necessary permissions GRANT CONNECT ON DATABASE myuploader TO app_user; GRANT USAGE ON SCHEMA public TO app_user; -- Grant table permissions (will be applied after tables are created) ALTER DEFAULT PRIVILEGES IN SCHEMA public GRANT SELECT, INSERT, UPDATE, DELETE ON TABLES TO app_user; ALTER DEFAULT PRIVILEGES IN SCHEMA public GRANT USAGE, SELECT ON SEQUENCES TO app_user; -- Create read-only user for monitoring/analytics DO $$ BEGIN CREATE USER readonly_user WITH PASSWORD 'readonly_password'; EXCEPTION WHEN duplicate_object THEN ALTER USER readonly_user WITH PASSWORD 'readonly_password'; END $$; GRANT CONNECT ON DATABASE myuploader TO readonly_user; GRANT USAGE ON SCHEMA public TO readonly_user; ALTER DEFAULT PRIVILEGES IN SCHEMA public GRANT SELECT ON TABLES TO readonly_user; -- Create backup user DO $$ BEGIN CREATE USER backup_user WITH PASSWORD 'backup_password'; EXCEPTION WHEN duplicate_object THEN ALTER USER backup_user WITH PASSWORD 'backup_password'; END $$; GRANT CONNECT ON DATABASE myuploader TO backup_user; GRANT USAGE ON SCHEMA public TO backup_user; ALTER DEFAULT PRIVILEGES IN SCHEMA public GRANT SELECT ON TABLES TO backup_user; -- Create audit log table for sensitive operations CREATE TABLE IF NOT EXISTS audit_log ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), user_id UUID, action VARCHAR(50) NOT NULL, table_name VARCHAR(50), record_id UUID, old_values JSONB, new_values JSONB, ip_address INET, user_agent TEXT, created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW() ); CREATE INDEX IF NOT EXISTS idx_audit_log_user_id ON audit_log(user_id); CREATE INDEX IF NOT EXISTS idx_audit_log_action ON audit_log(action); CREATE INDEX IF NOT EXISTS idx_audit_log_created_at ON audit_log(created_at); CREATE INDEX IF NOT EXISTS idx_audit_log_table_name ON audit_log(table_name); -- Create basic performance monitoring view CREATE OR REPLACE VIEW active_connections AS SELECT pid, usename, application_name, client_addr, client_port, backend_start, state, query_start, LEFT(query, 100) as query_preview FROM pg_stat_activity WHERE state != 'idle' AND pid != pg_backend_pid() ORDER BY backend_start; -- Grant permissions for monitoring GRANT SELECT ON active_connections TO readonly_user; -- Basic performance tuning for local development ALTER SYSTEM SET log_min_duration_statement = 1000; ALTER SYSTEM SET log_statement = 'mod'; ALTER SYSTEM SET log_line_prefix = '%t [%p]: [%l-1] user=%u,db=%d,app=%a,client=%h '; -- Connection settings optimized for local development ALTER SYSTEM SET max_connections = 100; ALTER SYSTEM SET shared_buffers = '128MB'; ALTER SYSTEM SET effective_cache_size = '512MB'; ALTER SYSTEM SET random_page_cost = 1.1; ALTER SYSTEM SET effective_io_concurrency = 200; -- IMPORTANT: SSL DISABLED FOR LOCAL DEVELOPMENT ALTER SYSTEM SET ssl = 'off'; ALTER SYSTEM SET log_connections = 'on'; ALTER SYSTEM SET log_disconnections = 'on'; ALTER SYSTEM SET log_lock_waits = 'on'; -- Reload configuration SELECT pg_reload_conf(); -- Display completion message DO $$ BEGIN RAISE NOTICE 'Local database initialization completed successfully!'; RAISE NOTICE 'SSL is DISABLED for local development'; RAISE NOTICE 'Remember to:'; RAISE NOTICE '1. Run initial migrations with Alembic'; RAISE NOTICE '2. Create your first admin user through the application'; RAISE NOTICE '3. For production: use init-db.sql with proper SSL setup'; END $$;