311 lines
10 KiB
PL/PgSQL
311 lines
10 KiB
PL/PgSQL
-- PostgreSQL initialization script for my-uploader-bot
|
|
-- This script sets up the database, users, and extensions
|
|
|
|
-- 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 performance monitoring functions
|
|
CREATE OR REPLACE FUNCTION get_table_stats()
|
|
RETURNS TABLE (
|
|
schema_name TEXT,
|
|
table_name TEXT,
|
|
row_count BIGINT,
|
|
total_size TEXT,
|
|
index_size TEXT,
|
|
toast_size TEXT
|
|
) AS $$
|
|
BEGIN
|
|
RETURN QUERY
|
|
SELECT
|
|
schemaname::TEXT,
|
|
tablename::TEXT,
|
|
n_tup_ins - n_tup_del AS row_count,
|
|
pg_size_pretty(pg_total_relation_size(schemaname||'.'||tablename)) AS total_size,
|
|
pg_size_pretty(pg_indexes_size(schemaname||'.'||tablename)) AS index_size,
|
|
pg_size_pretty(pg_total_relation_size(schemaname||'.'||tablename) - pg_relation_size(schemaname||'.'||tablename)) AS toast_size
|
|
FROM pg_stat_user_tables
|
|
WHERE schemaname = 'public'
|
|
ORDER BY pg_total_relation_size(schemaname||'.'||tablename) DESC;
|
|
END;
|
|
$$ LANGUAGE plpgsql SECURITY DEFINER;
|
|
|
|
-- Create index monitoring function
|
|
CREATE OR REPLACE FUNCTION get_unused_indexes()
|
|
RETURNS TABLE (
|
|
schema_name TEXT,
|
|
table_name TEXT,
|
|
index_name TEXT,
|
|
index_size TEXT,
|
|
index_scans BIGINT
|
|
) AS $$
|
|
BEGIN
|
|
RETURN QUERY
|
|
SELECT
|
|
schemaname::TEXT,
|
|
tablename::TEXT,
|
|
indexname::TEXT,
|
|
pg_size_pretty(pg_relation_size(indexrelid)) AS index_size,
|
|
idx_scan
|
|
FROM pg_stat_user_indexes
|
|
WHERE schemaname = 'public'
|
|
AND idx_scan < 100 -- Indexes used less than 100 times
|
|
ORDER BY pg_relation_size(indexrelid) DESC;
|
|
END;
|
|
$$ LANGUAGE plpgsql SECURITY DEFINER;
|
|
|
|
-- Create slow query logging configuration
|
|
ALTER SYSTEM SET log_min_duration_statement = 1000; -- Log queries taking more than 1 second
|
|
ALTER SYSTEM SET log_statement = 'mod'; -- Log modifications
|
|
ALTER SYSTEM SET log_line_prefix = '%t [%p]: [%l-1] user=%u,db=%d,app=%a,client=%h ';
|
|
|
|
-- 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 audit trigger function
|
|
CREATE OR REPLACE FUNCTION audit_trigger_function()
|
|
RETURNS TRIGGER AS $$
|
|
BEGIN
|
|
IF TG_OP = 'DELETE' THEN
|
|
INSERT INTO audit_log (action, table_name, record_id, old_values)
|
|
VALUES (TG_OP, TG_TABLE_NAME, OLD.id, row_to_json(OLD));
|
|
RETURN OLD;
|
|
ELSIF TG_OP = 'UPDATE' THEN
|
|
INSERT INTO audit_log (action, table_name, record_id, old_values, new_values)
|
|
VALUES (TG_OP, TG_TABLE_NAME, NEW.id, row_to_json(OLD), row_to_json(NEW));
|
|
RETURN NEW;
|
|
ELSIF TG_OP = 'INSERT' THEN
|
|
INSERT INTO audit_log (action, table_name, record_id, new_values)
|
|
VALUES (TG_OP, TG_TABLE_NAME, NEW.id, row_to_json(NEW));
|
|
RETURN NEW;
|
|
END IF;
|
|
RETURN NULL;
|
|
END;
|
|
$$ LANGUAGE plpgsql SECURITY DEFINER;
|
|
|
|
-- Create cleanup function for old audit logs
|
|
CREATE OR REPLACE FUNCTION cleanup_old_audit_logs(retention_days INTEGER DEFAULT 90)
|
|
RETURNS INTEGER AS $$
|
|
DECLARE
|
|
deleted_count INTEGER;
|
|
BEGIN
|
|
DELETE FROM audit_log
|
|
WHERE created_at < NOW() - INTERVAL '1 day' * retention_days;
|
|
|
|
GET DIAGNOSTICS deleted_count = ROW_COUNT;
|
|
RETURN deleted_count;
|
|
END;
|
|
$$ LANGUAGE plpgsql SECURITY DEFINER;
|
|
|
|
-- Create maintenance function
|
|
CREATE OR REPLACE FUNCTION run_maintenance()
|
|
RETURNS TEXT AS $$
|
|
DECLARE
|
|
result TEXT := '';
|
|
rec RECORD;
|
|
BEGIN
|
|
-- Update table statistics
|
|
ANALYZE;
|
|
result := result || 'Statistics updated. ';
|
|
|
|
-- Vacuum analyze all tables
|
|
FOR rec IN SELECT tablename FROM pg_tables WHERE schemaname = 'public' LOOP
|
|
EXECUTE 'VACUUM ANALYZE ' || quote_ident(rec.tablename);
|
|
END LOOP;
|
|
result := result || 'Vacuum completed. ';
|
|
|
|
-- Cleanup old audit logs (keep 90 days)
|
|
result := result || 'Cleaned up ' || cleanup_old_audit_logs(90) || ' old audit logs. ';
|
|
|
|
-- Reindex if needed (check for bloat)
|
|
FOR rec IN
|
|
SELECT schemaname, tablename
|
|
FROM pg_stat_user_tables
|
|
WHERE n_dead_tup > n_live_tup * 0.1
|
|
AND n_live_tup > 1000
|
|
LOOP
|
|
EXECUTE 'REINDEX TABLE ' || quote_ident(rec.schemaname) || '.' || quote_ident(rec.tablename);
|
|
result := result || 'Reindexed ' || rec.tablename || '. ';
|
|
END LOOP;
|
|
|
|
RETURN result;
|
|
END;
|
|
$$ LANGUAGE plpgsql SECURITY DEFINER;
|
|
|
|
-- Create backup verification function
|
|
CREATE OR REPLACE FUNCTION verify_backup_integrity()
|
|
RETURNS TABLE (
|
|
table_name TEXT,
|
|
row_count BIGINT,
|
|
last_modified TIMESTAMP WITH TIME ZONE,
|
|
checksum TEXT
|
|
) AS $$
|
|
BEGIN
|
|
RETURN QUERY
|
|
SELECT
|
|
t.tablename::TEXT,
|
|
t.n_live_tup,
|
|
GREATEST(t.last_vacuum, t.last_autovacuum, t.last_analyze, t.last_autoanalyze),
|
|
md5(string_agg(c.column_name, ',' ORDER BY c.ordinal_position))
|
|
FROM pg_stat_user_tables t
|
|
JOIN information_schema.columns c ON c.table_name = t.tablename
|
|
WHERE t.schemaname = 'public'
|
|
GROUP BY t.tablename, t.n_live_tup,
|
|
GREATEST(t.last_vacuum, t.last_autovacuum, t.last_analyze, t.last_autoanalyze)
|
|
ORDER BY t.tablename;
|
|
END;
|
|
$$ LANGUAGE plpgsql SECURITY DEFINER;
|
|
|
|
-- Create connection 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 functions
|
|
GRANT EXECUTE ON FUNCTION get_table_stats() TO readonly_user;
|
|
GRANT EXECUTE ON FUNCTION get_unused_indexes() TO readonly_user;
|
|
GRANT EXECUTE ON FUNCTION verify_backup_integrity() TO backup_user;
|
|
GRANT SELECT ON active_connections TO readonly_user;
|
|
|
|
-- Set up automatic maintenance schedule (requires pg_cron extension)
|
|
-- Uncomment if pg_cron is available
|
|
-- SELECT cron.schedule('database-maintenance', '0 2 * * 0', 'SELECT run_maintenance();');
|
|
-- SELECT cron.schedule('audit-cleanup', '0 3 * * *', 'SELECT cleanup_old_audit_logs(90);');
|
|
|
|
-- Create performance tuning settings
|
|
ALTER SYSTEM SET shared_preload_libraries = 'pg_stat_statements';
|
|
ALTER SYSTEM SET track_activity_query_size = 2048;
|
|
ALTER SYSTEM SET track_functions = 'all';
|
|
ALTER SYSTEM SET track_io_timing = 'on';
|
|
|
|
-- Connection pooling settings
|
|
ALTER SYSTEM SET max_connections = 200;
|
|
ALTER SYSTEM SET shared_buffers = '256MB';
|
|
ALTER SYSTEM SET effective_cache_size = '1GB';
|
|
ALTER SYSTEM SET maintenance_work_mem = '64MB';
|
|
ALTER SYSTEM SET checkpoint_completion_target = 0.9;
|
|
ALTER SYSTEM SET wal_buffers = '16MB';
|
|
ALTER SYSTEM SET default_statistics_target = 100;
|
|
ALTER SYSTEM SET random_page_cost = 1.1;
|
|
ALTER SYSTEM SET effective_io_concurrency = 200;
|
|
|
|
-- Security settings
|
|
ALTER SYSTEM SET ssl = 'on';
|
|
ALTER SYSTEM SET log_connections = 'on';
|
|
ALTER SYSTEM SET log_disconnections = 'on';
|
|
ALTER SYSTEM SET log_checkpoints = 'on';
|
|
ALTER SYSTEM SET log_lock_waits = 'on';
|
|
|
|
-- Reload configuration
|
|
SELECT pg_reload_conf();
|
|
|
|
-- Create initial admin user (password should be changed immediately)
|
|
-- This will be handled by the application during first startup
|
|
|
|
-- Display completion message
|
|
DO $$
|
|
BEGIN
|
|
RAISE NOTICE 'Database initialization completed successfully!';
|
|
RAISE NOTICE 'Remember to:';
|
|
RAISE NOTICE '1. Change default passwords for app_user, readonly_user, and backup_user';
|
|
RAISE NOTICE '2. Configure SSL certificates';
|
|
RAISE NOTICE '3. Set up regular backups';
|
|
RAISE NOTICE '4. Run initial migrations with Alembic';
|
|
RAISE NOTICE '5. Create your first admin user through the application';
|
|
END $$; |