Files
gt-ai-os-community/scripts/postgresql/migrations/T007_optimize_queries.sql
HackWeasel 310491a557 GT AI OS Community v2.0.33 - Add NVIDIA NIM and Nemotron agents
- Updated python_coding_microproject.csv to use NVIDIA NIM Kimi K2
- Updated kali_linux_shell_simulator.csv to use NVIDIA NIM Kimi K2
  - Made more general-purpose (flexible targets, expanded tools)
- Added nemotron-mini-agent.csv for fast local inference via Ollama
- Added nemotron-agent.csv for advanced reasoning via Ollama
- Added wiki page: Projects for NVIDIA NIMs and Nemotron
2025-12-12 17:47:14 -05:00

62 lines
2.3 KiB
PL/PgSQL

-- T007_optimize_queries.sql
-- Phase 1 Performance Optimization: Composite Indexes
-- Creates composite indexes for common query patterns to improve performance
-- Estimated improvement: 60-80% faster conversation and message queries
BEGIN;
-- Apply to all existing tenant schemas
DO $$
DECLARE
tenant_schema TEXT;
BEGIN
FOR tenant_schema IN
SELECT schema_name
FROM information_schema.schemata
WHERE schema_name LIKE 'tenant_%' AND schema_name != 'tenant_template'
LOOP
-- Composite index for message queries
-- Optimizes: SELECT * FROM messages WHERE conversation_id = ? ORDER BY created_at
-- Common in: conversation_service.get_messages() with pagination
-- Impact: Covers both filter and sort in single index scan
EXECUTE format('
CREATE INDEX IF NOT EXISTS idx_messages_conversation_created
ON %I.messages
USING btree (conversation_id, created_at ASC)
', tenant_schema);
-- Composite index for conversation list queries
-- Optimizes: SELECT * FROM conversations WHERE user_id = ? AND is_archived = false ORDER BY updated_at DESC
-- Common in: conversation_service.list_conversations()
-- Impact: Enables index-only scan for conversation lists
EXECUTE format('
CREATE INDEX IF NOT EXISTS idx_conversations_user_updated
ON %I.conversations
USING btree (user_id, is_archived, updated_at DESC)
', tenant_schema);
RAISE NOTICE 'Applied T007 optimization indexes to schema: %', tenant_schema;
END LOOP;
END $$;
COMMIT;
-- Performance Notes:
-- - Both indexes support common access patterns in the application
-- - No schema changes - purely additive optimization
-- - Safe to run multiple times (IF NOT EXISTS)
-- - Note: CONCURRENTLY cannot be used inside DO $$ blocks
--
-- Rollback (if needed):
-- DO $$
-- DECLARE tenant_schema TEXT;
-- BEGIN
-- FOR tenant_schema IN
-- SELECT schema_name FROM information_schema.schemata
-- WHERE schema_name LIKE 'tenant_%' AND schema_name != 'tenant_template'
-- LOOP
-- EXECUTE format('DROP INDEX IF EXISTS %I.idx_messages_conversation_created', tenant_schema);
-- EXECUTE format('DROP INDEX IF EXISTS %I.idx_conversations_user_updated', tenant_schema);
-- END LOOP;
-- END $$;