Files
calypso/backend/internal/common/database/migrations/003_performance_indexes.sql
2025-12-24 19:53:45 +00:00

175 lines
8.2 KiB
SQL

-- AtlasOS - Calypso
-- Performance Optimization: Database Indexes
-- Version: 3.0
-- Description: Adds indexes for frequently queried columns to improve query performance
-- ============================================================================
-- Authentication & Authorization Indexes
-- ============================================================================
-- Users table indexes
-- Username is frequently queried during login
CREATE INDEX IF NOT EXISTS idx_users_username ON users(username);
-- Email lookups
CREATE INDEX IF NOT EXISTS idx_users_email ON users(email);
-- Active user lookups
CREATE INDEX IF NOT EXISTS idx_users_is_active ON users(is_active) WHERE is_active = true;
-- Sessions table indexes
-- Token hash lookups are very frequent (every authenticated request)
CREATE INDEX IF NOT EXISTS idx_sessions_token_hash ON sessions(token_hash);
-- User session lookups
CREATE INDEX IF NOT EXISTS idx_sessions_user_id ON sessions(user_id);
-- Expired session cleanup (index on expires_at for efficient cleanup queries)
CREATE INDEX IF NOT EXISTS idx_sessions_expires_at ON sessions(expires_at);
-- User roles junction table
-- Lookup roles for a user (frequent during permission checks)
CREATE INDEX IF NOT EXISTS idx_user_roles_user_id ON user_roles(user_id);
-- Lookup users with a role
CREATE INDEX IF NOT EXISTS idx_user_roles_role_id ON user_roles(role_id);
-- Role permissions junction table
-- Lookup permissions for a role
CREATE INDEX IF NOT EXISTS idx_role_permissions_role_id ON role_permissions(role_id);
-- Lookup roles with a permission
CREATE INDEX IF NOT EXISTS idx_role_permissions_permission_id ON role_permissions(permission_id);
-- ============================================================================
-- Audit & Monitoring Indexes
-- ============================================================================
-- Audit log indexes
-- Time-based queries (most common audit log access pattern)
CREATE INDEX IF NOT EXISTS idx_audit_log_created_at ON audit_log(created_at DESC);
-- User activity queries
CREATE INDEX IF NOT EXISTS idx_audit_log_user_id ON audit_log(user_id);
-- Resource-based queries
CREATE INDEX IF NOT EXISTS idx_audit_log_resource ON audit_log(resource_type, resource_id);
-- Alerts table indexes
-- Time-based ordering (default ordering in ListAlerts)
CREATE INDEX IF NOT EXISTS idx_alerts_created_at ON alerts(created_at DESC);
-- Severity filtering
CREATE INDEX IF NOT EXISTS idx_alerts_severity ON alerts(severity);
-- Source filtering
CREATE INDEX IF NOT EXISTS idx_alerts_source ON alerts(source);
-- Acknowledgment status
CREATE INDEX IF NOT EXISTS idx_alerts_acknowledged ON alerts(is_acknowledged) WHERE is_acknowledged = false;
-- Resource-based queries
CREATE INDEX IF NOT EXISTS idx_alerts_resource ON alerts(resource_type, resource_id);
-- Composite index for common filter combinations
CREATE INDEX IF NOT EXISTS idx_alerts_severity_acknowledged ON alerts(severity, is_acknowledged, created_at DESC);
-- ============================================================================
-- Task Management Indexes
-- ============================================================================
-- Tasks table indexes
-- Status filtering (very common in task queries)
CREATE INDEX IF NOT EXISTS idx_tasks_status ON tasks(status);
-- Created by user
CREATE INDEX IF NOT EXISTS idx_tasks_created_by ON tasks(created_by);
-- Time-based queries
CREATE INDEX IF NOT EXISTS idx_tasks_created_at ON tasks(created_at DESC);
-- Status + time composite (common query pattern)
CREATE INDEX IF NOT EXISTS idx_tasks_status_created_at ON tasks(status, created_at DESC);
-- Failed tasks lookup (for alerting)
CREATE INDEX IF NOT EXISTS idx_tasks_failed_recent ON tasks(status, created_at DESC) WHERE status = 'failed';
-- ============================================================================
-- Storage Indexes
-- ============================================================================
-- Disk repositories indexes
-- Active repository lookups
CREATE INDEX IF NOT EXISTS idx_disk_repositories_is_active ON disk_repositories(is_active) WHERE is_active = true;
-- Name lookups
CREATE INDEX IF NOT EXISTS idx_disk_repositories_name ON disk_repositories(name);
-- Volume group lookups
CREATE INDEX IF NOT EXISTS idx_disk_repositories_vg ON disk_repositories(volume_group);
-- Physical disks indexes
-- Device path lookups (for sync operations)
CREATE INDEX IF NOT EXISTS idx_physical_disks_device_path ON physical_disks(device_path);
-- ============================================================================
-- SCST Indexes
-- ============================================================================
-- SCST targets indexes
-- IQN lookups (frequent during target operations)
CREATE INDEX IF NOT EXISTS idx_scst_targets_iqn ON scst_targets(iqn);
-- Active target lookups
CREATE INDEX IF NOT EXISTS idx_scst_targets_is_active ON scst_targets(is_active) WHERE is_active = true;
-- SCST LUNs indexes
-- Target + LUN lookups (very frequent)
CREATE INDEX IF NOT EXISTS idx_scst_luns_target_lun ON scst_luns(target_id, lun_number);
-- Device path lookups
CREATE INDEX IF NOT EXISTS idx_scst_luns_device_path ON scst_luns(device_path);
-- SCST initiator groups indexes
-- Target + group name lookups
CREATE INDEX IF NOT EXISTS idx_scst_initiator_groups_target ON scst_initiator_groups(target_id);
-- Group name lookups
CREATE INDEX IF NOT EXISTS idx_scst_initiator_groups_name ON scst_initiator_groups(group_name);
-- SCST initiators indexes
-- Group + IQN lookups
CREATE INDEX IF NOT EXISTS idx_scst_initiators_group_iqn ON scst_initiators(group_id, iqn);
-- Active initiator lookups
CREATE INDEX IF NOT EXISTS idx_scst_initiators_is_active ON scst_initiators(is_active) WHERE is_active = true;
-- ============================================================================
-- Tape Library Indexes
-- ============================================================================
-- Physical tape libraries indexes
-- Serial number lookups (for discovery)
CREATE INDEX IF NOT EXISTS idx_physical_tape_libraries_serial ON physical_tape_libraries(serial_number);
-- Active library lookups
CREATE INDEX IF NOT EXISTS idx_physical_tape_libraries_is_active ON physical_tape_libraries(is_active) WHERE is_active = true;
-- Physical tape drives indexes
-- Library + drive number lookups (very frequent)
CREATE INDEX IF NOT EXISTS idx_physical_tape_drives_library_drive ON physical_tape_drives(library_id, drive_number);
-- Status filtering
CREATE INDEX IF NOT EXISTS idx_physical_tape_drives_status ON physical_tape_drives(status);
-- Physical tape slots indexes
-- Library + slot number lookups
CREATE INDEX IF NOT EXISTS idx_physical_tape_slots_library_slot ON physical_tape_slots(library_id, slot_number);
-- Barcode lookups
CREATE INDEX IF NOT EXISTS idx_physical_tape_slots_barcode ON physical_tape_slots(barcode) WHERE barcode IS NOT NULL;
-- Virtual tape libraries indexes
-- MHVTL library ID lookups
CREATE INDEX IF NOT EXISTS idx_virtual_tape_libraries_mhvtl_id ON virtual_tape_libraries(mhvtl_library_id);
-- Active library lookups
CREATE INDEX IF NOT EXISTS idx_virtual_tape_libraries_is_active ON virtual_tape_libraries(is_active) WHERE is_active = true;
-- Virtual tape drives indexes
-- Library + drive number lookups (very frequent)
CREATE INDEX IF NOT EXISTS idx_virtual_tape_drives_library_drive ON virtual_tape_drives(library_id, drive_number);
-- Status filtering
CREATE INDEX IF NOT EXISTS idx_virtual_tape_drives_status ON virtual_tape_drives(status);
-- Current tape lookups
CREATE INDEX IF NOT EXISTS idx_virtual_tape_drives_current_tape ON virtual_tape_drives(current_tape_id) WHERE current_tape_id IS NOT NULL;
-- Virtual tapes indexes
-- Library + slot number lookups
CREATE INDEX IF NOT EXISTS idx_virtual_tapes_library_slot ON virtual_tapes(library_id, slot_number);
-- Barcode lookups
CREATE INDEX IF NOT EXISTS idx_virtual_tapes_barcode ON virtual_tapes(barcode) WHERE barcode IS NOT NULL;
-- Status filtering
CREATE INDEX IF NOT EXISTS idx_virtual_tapes_status ON virtual_tapes(status);
-- ============================================================================
-- Statistics Update
-- ============================================================================
-- Update table statistics for query planner
ANALYZE;