Files
biblical-guide.com/scripts/old/optimize-db.sql
Andrei 95070e5369 Add comprehensive page management system to admin dashboard
Features added:
- Database schema for pages and media files with content types (Rich Text, HTML, Markdown)
- Admin API routes for full page CRUD operations
- Image upload functionality with file management
- Rich text editor using TinyMCE with image insertion
- Admin interface for creating/editing pages with SEO options
- Dynamic navigation and footer integration
- Public page display routes with proper SEO metadata
- Support for featured images and content excerpts

Admin features:
- Create/edit/delete pages with rich content editor
- Upload and manage images through media library
- Configure pages to appear in navigation or footer
- Set page status (Draft, Published, Archived)
- SEO title and description management
- Real-time preview of content changes

🤖 Generated with [Claude Code](https://claude.ai/code)

Co-Authored-By: Claude <noreply@anthropic.com>
2025-09-24 07:26:25 +00:00

140 lines
4.6 KiB
PL/PgSQL

-- Database Performance Optimization Script
-- Create materialized view for popular verses
CREATE MATERIALIZED VIEW IF NOT EXISTS popular_verses AS
SELECT
v.id,
v.text,
b.name as book_name,
c."chapterNum",
v."verseNum",
COUNT(bm.id) as bookmark_count
FROM "BibleVerse" v
JOIN "BibleChapter" c ON v."chapterId" = c.id
JOIN "BibleBook" b ON c."bookId" = b.id
LEFT JOIN "Bookmark" bm ON v.id = bm."verseId"
GROUP BY v.id, v.text, b.name, c."chapterNum", v."verseNum"
ORDER BY bookmark_count DESC
LIMIT 100;
-- Create unique index on materialized view
CREATE UNIQUE INDEX IF NOT EXISTS popular_verses_id_idx ON popular_verses (id);
-- Function to refresh popular verses materialized view
CREATE OR REPLACE FUNCTION refresh_popular_verses()
RETURNS void AS $$
BEGIN
REFRESH MATERIALIZED VIEW CONCURRENTLY popular_verses;
END;
$$ LANGUAGE plpgsql;
-- Create additional performance indexes
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_chat_messages_user_created ON "ChatMessage"("userId", "createdAt" DESC);
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_bookmarks_user_created ON "Bookmark"("userId", "createdAt" DESC);
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_reading_history_user_viewed ON "ReadingHistory"("userId", "viewedAt" DESC);
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_prayer_requests_created ON "PrayerRequest"("createdAt" DESC);
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_notes_user_created ON "Note"("userId", "createdAt" DESC);
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_sessions_expires ON "Session"("expiresAt");
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_user_preferences_user_key ON "UserPreference"("userId", "key");
-- Create partial indexes for better performance
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_active_sessions ON "Session"("userId") WHERE "expiresAt" > NOW();
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_recent_prayers ON "PrayerRequest"("createdAt") WHERE "createdAt" > NOW() - INTERVAL '30 days';
-- Function to analyze query performance
CREATE OR REPLACE FUNCTION analyze_query_performance()
RETURNS void AS $$
BEGIN
-- Update table statistics
ANALYZE "User";
ANALYZE "Session";
ANALYZE "BibleBook";
ANALYZE "BibleChapter";
ANALYZE "BibleVerse";
ANALYZE "ChatMessage";
ANALYZE "Bookmark";
ANALYZE "Note";
ANALYZE "PrayerRequest";
ANALYZE "Prayer";
ANALYZE "ReadingHistory";
ANALYZE "UserPreference";
ANALYZE verse_cache;
-- Refresh materialized view
PERFORM refresh_popular_verses();
END;
$$ LANGUAGE plpgsql;
-- Function to cleanup old data
CREATE OR REPLACE FUNCTION cleanup_old_data()
RETURNS void AS $$
BEGIN
-- Clean up expired sessions
DELETE FROM "Session" WHERE "expiresAt" < NOW();
-- Clean up expired cache entries
DELETE FROM verse_cache WHERE expires_at < NOW();
-- Clean up old reading history (older than 1 year)
DELETE FROM "ReadingHistory" WHERE "viewedAt" < NOW() - INTERVAL '1 year';
-- Clean up old anonymous prayer requests (older than 6 months)
DELETE FROM "PrayerRequest"
WHERE "isAnonymous" = true
AND "createdAt" < NOW() - INTERVAL '6 months';
-- Vacuum and analyze after cleanup
VACUUM ANALYZE;
END;
$$ LANGUAGE plpgsql;
-- Create function to monitor database size
CREATE OR REPLACE FUNCTION get_database_stats()
RETURNS TABLE(
table_name TEXT,
row_count BIGINT,
table_size TEXT,
index_size TEXT,
total_size TEXT
) AS $$
BEGIN
RETURN QUERY
SELECT
schemaname || '.' || tablename AS table_name,
n_tup_ins - n_tup_del AS row_count,
pg_size_pretty(pg_total_relation_size(schemaname||'.'||tablename)) AS table_size,
pg_size_pretty(pg_indexes_size(schemaname||'.'||tablename)) AS index_size,
pg_size_pretty(pg_total_relation_size(schemaname||'.'||tablename) + pg_indexes_size(schemaname||'.'||tablename)) AS total_size
FROM pg_stat_user_tables
WHERE schemaname = 'public'
ORDER BY pg_total_relation_size(schemaname||'.'||tablename) DESC;
END;
$$ LANGUAGE plpgsql;
-- Create function to get slow queries
CREATE OR REPLACE FUNCTION get_slow_queries()
RETURNS TABLE(
query TEXT,
calls BIGINT,
total_time DOUBLE PRECISION,
mean_time DOUBLE PRECISION,
stddev_time DOUBLE PRECISION
) AS $$
BEGIN
RETURN QUERY
SELECT
pg_stat_statements.query,
pg_stat_statements.calls,
pg_stat_statements.total_exec_time,
pg_stat_statements.mean_exec_time,
pg_stat_statements.stddev_exec_time
FROM pg_stat_statements
WHERE pg_stat_statements.mean_exec_time > 100 -- queries taking more than 100ms on average
ORDER BY pg_stat_statements.mean_exec_time DESC
LIMIT 20;
EXCEPTION
WHEN undefined_table THEN
RAISE NOTICE 'pg_stat_statements extension not available';
RETURN;
END;
$$ LANGUAGE plpgsql;