feat(database): add performance indexes and materialized view for optimization

- Created multiple new indexes in the performance-indexes.sql file to enhance query performance for tasks, team members, and related tables.
- Added a materialized view for team member information in 3_views.sql to pre-calculate expensive joins, improving data retrieval efficiency.
- Introduced a function to refresh the materialized view, ensuring up-to-date information while optimizing performance.
- Implemented an optimized method in tasks-controller-v2.ts to split complex queries into focused segments, significantly improving response times and overall performance.
This commit is contained in:
chamikaJ
2025-07-07 15:01:11 +05:30
parent 134899114d
commit 978d9158c0
3 changed files with 397 additions and 1 deletions

View File

@@ -79,4 +79,57 @@ ON task_priorities(value);
-- Index for team labels
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_team_labels_team
ON team_labels(team_id);
ON team_labels(team_id);
-- NEW INDEXES FOR PERFORMANCE OPTIMIZATION --
-- Composite index for task main query optimization (covers most WHERE conditions)
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_tasks_performance_main
ON tasks(project_id, archived, parent_task_id, status_id, priority_id)
WHERE archived = FALSE;
-- Index for sorting by sort_order with project filter
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_tasks_project_sort_order
ON tasks(project_id, sort_order)
WHERE archived = FALSE;
-- Index for email_invitations to optimize team_member_info_view
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_email_invitations_team_member
ON email_invitations(team_member_id);
-- Covering index for task status with category information
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_task_statuses_covering
ON task_statuses(id, category_id, project_id);
-- Index for task aggregation queries (parent task progress calculation)
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_tasks_parent_status_archived
ON tasks(parent_task_id, status_id, archived)
WHERE archived = FALSE;
-- Index for project team member filtering
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_team_members_project_lookup
ON team_members(team_id, active, user_id)
WHERE active = TRUE;
-- Covering index for tasks with frequently accessed columns
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_tasks_covering_main
ON tasks(id, project_id, archived, parent_task_id, status_id, priority_id, sort_order, name)
WHERE archived = FALSE;
-- Index for task search functionality
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_tasks_name_search
ON tasks USING gin(to_tsvector('english', name))
WHERE archived = FALSE;
-- Index for date-based filtering (if used)
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_tasks_dates
ON tasks(project_id, start_date, end_date)
WHERE archived = FALSE;
-- Index for task timers with user filtering
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_task_timers_user_task
ON task_timers(user_id, task_id);
-- Index for sys_task_status_categories lookups
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_sys_task_status_categories_covering
ON sys_task_status_categories(id, color_code, color_code_dark, is_done, is_doing, is_todo);