feat(sort-orders): implement separate sort orders for task groupings

- Introduced new columns for `status_sort_order`, `priority_sort_order`, `phase_sort_order`, and `member_sort_order` in the tasks table to maintain distinct sort orders for each grouping type.
- Updated database functions to handle grouping-specific sort orders and avoid unique constraint violations.
- Enhanced backend socket handlers to emit changes based on the selected grouping.
- Modified frontend components to support drag-and-drop functionality with the new sort order fields, ensuring task organization is preserved across different views.
- Added comprehensive migration scripts and verification steps to ensure smooth deployment and backward compatibility.
This commit is contained in:
chamiakJ
2025-07-15 07:44:15 +05:30
parent e87f33dcc8
commit 407dc416ec
12 changed files with 974 additions and 72 deletions

View File

@@ -0,0 +1,140 @@
# Deployment Guide: Separate Sort Orders Feature
## Issue Resolution
The unique constraint error `"duplicate key value violates unique constraint tasks_sort_order_unique"` has been fixed by ensuring that:
1. The new grouping-specific sort columns don't have unique constraints
2. We only update the main `sort_order` column when explicitly needed
3. Database functions properly handle the different sort columns
## Required Migrations (Run in Order)
### 1. Schema Changes
```bash
psql -d worklenz -f database/migrations/20250715000000-add-grouping-sort-orders.sql
```
### 2. Function Updates
```bash
psql -d worklenz -f database/migrations/20250715000001-update-sort-functions.sql
```
### 3. Constraint Fixes
```bash
psql -d worklenz -f database/migrations/20250715000002-fix-sort-constraint.sql
```
## Verification Steps
### 1. Test Database Functions
```bash
psql -d worklenz -f test_sort_fix.sql
```
### 2. Verify Schema
```sql
-- Check new columns exist
\d tasks
-- Verify helper function works
SELECT get_sort_column_name('status');
```
### 3. Test Sort Operations
```sql
-- Test bulk update (replace with real UUIDs)
SELECT update_task_sort_orders_bulk(
'[{"task_id": "real-uuid", "sort_order": 1}]'::json,
'status'
);
```
## Key Changes Made
### Database Layer
- **New Columns:** Added `status_sort_order`, `priority_sort_order`, `phase_sort_order`, `member_sort_order`
- **No Unique Constraints:** New columns allow duplicate values (by design)
- **Fixed Functions:** Updated to avoid touching `sort_order` column unnecessarily
- **Data Migration:** Existing tasks get their current `sort_order` copied to all new columns
### Backend Layer
- **Socket Handler:** Updated to use correct sort column based on `group_by`
- **Function Calls:** Pass grouping parameter to database functions
- **Error Handling:** Avoid constraint violations by working with right columns
### Frontend Layer
- **Type Safety:** Added new sort order fields to Task interface
- **Helper Function:** `getSortOrderField()` for consistent field selection
- **Redux Updates:** Use appropriate sort field in state management
- **Drag & Drop:** Updated to work with grouping-specific sort orders
## Behavior Changes
### Before Fix
- All groupings shared same `sort_order` column
- Constraint violations when multiple tasks had same sort value
- Lost organization when switching between grouping views
### After Fix
- Each grouping type has its own sort order column
- No constraint violations (new columns don't have unique constraints)
- Task organization preserved when switching between views
- Backward compatible with existing data
## Troubleshooting
### If Migration Fails
1. **Check Permissions:** Ensure database user has CREATE/ALTER privileges
2. **Backup First:** Always backup before running migrations
3. **Check Dependencies:** Ensure functions `is_null_or_empty` exists
### If Constraint Errors Persist
1. **Check Which Column:** Error should specify which column is causing the issue
2. **Run Data Fix:** The migration includes a data cleanup step
3. **Verify Functions:** Ensure updated functions are being used
### Rollback Plan
```sql
-- If needed, rollback to original functions
-- (Save original function definitions first)
-- Remove new columns (WARNING: This loses data)
ALTER TABLE tasks DROP COLUMN IF EXISTS status_sort_order;
ALTER TABLE tasks DROP COLUMN IF EXISTS priority_sort_order;
ALTER TABLE tasks DROP COLUMN IF EXISTS phase_sort_order;
ALTER TABLE tasks DROP COLUMN IF EXISTS member_sort_order;
```
## Performance Impact
### Positive
- ✅ Better user experience with preserved sort orders
- ✅ More efficient queries (appropriate indexes added)
- ✅ Reduced conflicts during concurrent operations
### Considerations
- 📊 Minimal storage increase (4 integers per task)
- 📊 Slightly more complex database functions
- 📊 No significant performance impact expected
## Testing Checklist
- [ ] Migrations run successfully without errors
- [ ] New columns exist and are populated
- [ ] Helper functions return correct column names
- [ ] Drag and drop works in status view
- [ ] Drag and drop works in priority view
- [ ] Drag and drop works in phase view
- [ ] Drag and drop works in member view
- [ ] Sort orders persist when switching between views
- [ ] No constraint violation errors in logs
- [ ] Existing functionality still works
- [ ] Performance is acceptable
## Success Metrics
After deployment, verify:
1. **No Error Logs:** No constraint violation errors in application logs
2. **User Feedback:** Users can organize tasks differently in different views
3. **Data Integrity:** Task sort orders are preserved correctly
4. **Performance:** No significant slowdown in task operations

View File

@@ -0,0 +1,162 @@
# Separate Sort Orders Implementation
## Overview
This implementation adds support for maintaining different task sort orders for each grouping type (status, priority, phase, members). This allows users to organize tasks differently when switching between different views while preserving their organization intent.
## Changes Made
### 1. Database Schema Changes
**File:** `/database/migrations/20250715000000-add-grouping-sort-orders.sql`
- Added 4 new columns to the `tasks` table:
- `status_sort_order` - Sort order when grouped by status
- `priority_sort_order` - Sort order when grouped by priority
- `phase_sort_order` - Sort order when grouped by phase
- `member_sort_order` - Sort order when grouped by members/assignees
- Added constraints and indexes for performance
- Initialized new columns with current `sort_order` values for backward compatibility
### 2. Database Functions Update
**File:** `/database/migrations/20250715000001-update-sort-functions.sql`
- **`get_sort_column_name()`** - Helper function to get appropriate column name based on grouping
- **`update_task_sort_orders_bulk()`** - Updated to accept grouping parameter and update correct sort column
- **`handle_task_list_sort_order_change()`** - Updated to use dynamic SQL for different sort columns
### 3. Backend Socket Handler Updates
**File:** `/src/socket.io/commands/on-task-sort-order-change.ts`
- Updated `emitSortOrderChange()` to use appropriate sort column based on `group_by`
- Modified bulk update calls to pass `group_by` parameter
- Enhanced query to return both general and current sort orders
### 4. Frontend Type Definitions
**File:** `/src/types/task-management.types.ts`
- Added new sort order fields to `Task` interface
- Created `getSortOrderField()` helper function for type-safe field selection
### 5. Redux State Management
**File:** `/src/features/task-management/task-management.slice.ts`
- Updated `reorderTasksInGroup` reducer to use appropriate sort field based on grouping
- Integrated `getSortOrderField()` helper for consistent field selection
### 6. Drag and Drop Implementation
**File:** `/src/components/task-list-v2/hooks/useDragAndDrop.ts`
- Updated `emitTaskSortChange()` to use grouping-specific sort order fields
- Enhanced sort order calculation to work with different sort columns
## Usage Examples
### User Experience
1. **Status View:** User arranges tasks by business priority within each status column
2. **Priority View:** User switches to priority view - tasks maintain their status-specific order within each priority group
3. **Phase View:** User switches to phase view - tasks maintain their own organization within each phase
4. **Back to Status:** Returning to status view shows the original organization
### API Usage
```javascript
// Socket emission now includes group_by parameter
socket.emit('TASK_SORT_ORDER_CHANGE', {
project_id: 'uuid',
group_by: 'status', // 'status', 'priority', 'phase', 'members'
task_updates: [{
task_id: 'uuid',
sort_order: 1,
status_id: 'uuid' // if moving between status groups
}]
});
```
### Database Query Examples
```sql
-- Get tasks ordered by status grouping
SELECT * FROM tasks
WHERE project_id = $1
ORDER BY status_sort_order;
-- Get tasks ordered by priority grouping
SELECT * FROM tasks
WHERE project_id = $1
ORDER BY priority_sort_order;
```
## Migration Steps
1. **Run Database Migrations:**
```bash
# Apply schema changes
psql -d worklenz -f database/migrations/20250715000000-add-grouping-sort-orders.sql
# Apply function updates
psql -d worklenz -f database/migrations/20250715000001-update-sort-functions.sql
```
2. **Test Migration:**
```bash
# Verify columns and functions
psql -d worklenz -f test_sort_orders.sql
```
3. **Deploy Frontend Changes:**
- No additional steps needed - changes are backward compatible
- Users will immediately benefit from separate sort orders
## Backward Compatibility
- ✅ Existing `sort_order` column remains unchanged
- ✅ New columns initialized with current `sort_order` values
- ✅ Old API calls continue to work (default to status grouping)
- ✅ Frontend gracefully falls back to `order` field if new fields not available
## Performance Considerations
- Added indexes on new sort order columns for efficient ordering
- Dynamic SQL in functions is minimal and safe (controlled input)
- Memory footprint increase is minimal (4 integers per task)
## Testing
1. **Database Level:**
- Verify migrations run successfully
- Test function calls with different grouping parameters
- Validate indexes are created and used
2. **API Level:**
- Test socket emissions with different `group_by` values
- Verify correct sort columns are updated
- Test cross-group task moves
3. **Frontend Level:**
- Test drag and drop in different grouping views
- Verify sort order persistence when switching views
- Test that original behavior is preserved
## Future Enhancements
1. **UI Indicators:** Show users which view they're currently organizing
2. **Sort Order Reset:** Allow users to reset sort orders for specific groupings
3. **Export/Import:** Include sort order data in project templates
4. **Analytics:** Track how users organize tasks in different views
## Troubleshooting
### Common Issues:
1. **Migration Fails:** Check database permissions and existing data integrity
2. **Sort Orders Not Persisting:** Verify socket handler receives `group_by` parameter
3. **Tasks Not Reordering:** Check frontend Redux state updates and sort field usage
### Debug Queries:
```sql
-- Check current sort orders for a project
SELECT id, name, status_sort_order, priority_sort_order, phase_sort_order, member_sort_order
FROM tasks
WHERE project_id = 'your-project-id'
ORDER BY status_sort_order;
-- Verify function calls
SELECT get_sort_column_name('status'); -- Should return 'status_sort_order'
```

41
test_sort_fix.sql Normal file
View File

@@ -0,0 +1,41 @@
-- Test script to verify the sort order constraint fix
-- Test the helper function
SELECT get_sort_column_name('status'); -- Should return 'status_sort_order'
SELECT get_sort_column_name('priority'); -- Should return 'priority_sort_order'
SELECT get_sort_column_name('phase'); -- Should return 'phase_sort_order'
SELECT get_sort_column_name('members'); -- Should return 'member_sort_order'
SELECT get_sort_column_name('unknown'); -- Should return 'status_sort_order' (default)
-- Test bulk update function (example - would need real project_id and task_ids)
/*
SELECT update_task_sort_orders_bulk(
'[
{"task_id": "example-uuid", "sort_order": 1, "status_id": "status-uuid"},
{"task_id": "example-uuid-2", "sort_order": 2, "status_id": "status-uuid"}
]'::json,
'status'
);
*/
-- Verify that sort_order constraint still exists and works
SELECT
tc.constraint_name,
tc.table_name,
kcu.column_name
FROM information_schema.table_constraints tc
JOIN information_schema.key_column_usage kcu
ON tc.constraint_name = kcu.constraint_name
WHERE tc.constraint_name = 'tasks_sort_order_unique';
-- Check that new sort order columns don't have unique constraints (which is correct)
SELECT
tc.constraint_name,
tc.table_name,
kcu.column_name
FROM information_schema.table_constraints tc
JOIN information_schema.key_column_usage kcu
ON tc.constraint_name = kcu.constraint_name
WHERE kcu.table_name = 'tasks'
AND kcu.column_name IN ('status_sort_order', 'priority_sort_order', 'phase_sort_order', 'member_sort_order')
AND tc.constraint_type = 'UNIQUE';

30
test_sort_orders.sql Normal file
View File

@@ -0,0 +1,30 @@
-- Test script to validate the separate sort order implementation
-- Check if new columns exist
SELECT column_name, data_type, is_nullable, column_default
FROM information_schema.columns
WHERE table_name = 'tasks'
AND column_name IN ('status_sort_order', 'priority_sort_order', 'phase_sort_order', 'member_sort_order')
ORDER BY column_name;
-- Check if helper function exists
SELECT routine_name, routine_type
FROM information_schema.routines
WHERE routine_name IN ('get_sort_column_name', 'update_task_sort_orders_bulk', 'handle_task_list_sort_order_change');
-- Sample test data to verify different sort orders work
-- (This would be run after the migrations)
/*
-- Test: Tasks should have different orders for different groupings
SELECT
id,
name,
sort_order,
status_sort_order,
priority_sort_order,
phase_sort_order,
member_sort_order
FROM tasks
WHERE project_id = '<test-project-id>'
ORDER BY status_sort_order;
*/

View File

@@ -0,0 +1,37 @@
-- Migration: Add separate sort order columns for different grouping types
-- This allows users to maintain different task orders when switching between grouping views
-- Add new sort order columns
ALTER TABLE tasks ADD COLUMN IF NOT EXISTS status_sort_order INTEGER DEFAULT 0;
ALTER TABLE tasks ADD COLUMN IF NOT EXISTS priority_sort_order INTEGER DEFAULT 0;
ALTER TABLE tasks ADD COLUMN IF NOT EXISTS phase_sort_order INTEGER DEFAULT 0;
ALTER TABLE tasks ADD COLUMN IF NOT EXISTS member_sort_order INTEGER DEFAULT 0;
-- Initialize new columns with current sort_order values
UPDATE tasks SET
status_sort_order = sort_order,
priority_sort_order = sort_order,
phase_sort_order = sort_order,
member_sort_order = sort_order
WHERE status_sort_order = 0
OR priority_sort_order = 0
OR phase_sort_order = 0
OR member_sort_order = 0;
-- Add constraints to ensure non-negative values
ALTER TABLE tasks ADD CONSTRAINT tasks_status_sort_order_check CHECK (status_sort_order >= 0);
ALTER TABLE tasks ADD CONSTRAINT tasks_priority_sort_order_check CHECK (priority_sort_order >= 0);
ALTER TABLE tasks ADD CONSTRAINT tasks_phase_sort_order_check CHECK (phase_sort_order >= 0);
ALTER TABLE tasks ADD CONSTRAINT tasks_member_sort_order_check CHECK (member_sort_order >= 0);
-- Add indexes for performance (since these will be used for ordering)
CREATE INDEX IF NOT EXISTS idx_tasks_status_sort_order ON tasks(project_id, status_sort_order);
CREATE INDEX IF NOT EXISTS idx_tasks_priority_sort_order ON tasks(project_id, priority_sort_order);
CREATE INDEX IF NOT EXISTS idx_tasks_phase_sort_order ON tasks(project_id, phase_sort_order);
CREATE INDEX IF NOT EXISTS idx_tasks_member_sort_order ON tasks(project_id, member_sort_order);
-- Update comments for documentation
COMMENT ON COLUMN tasks.status_sort_order IS 'Sort order when grouped by status';
COMMENT ON COLUMN tasks.priority_sort_order IS 'Sort order when grouped by priority';
COMMENT ON COLUMN tasks.phase_sort_order IS 'Sort order when grouped by phase';
COMMENT ON COLUMN tasks.member_sort_order IS 'Sort order when grouped by members/assignees';

View File

@@ -0,0 +1,172 @@
-- Migration: Update database functions to handle grouping-specific sort orders
-- Function to get the appropriate sort column name based on grouping type
CREATE OR REPLACE FUNCTION get_sort_column_name(_group_by TEXT) RETURNS TEXT
LANGUAGE plpgsql
AS
$$
BEGIN
CASE _group_by
WHEN 'status' THEN RETURN 'status_sort_order';
WHEN 'priority' THEN RETURN 'priority_sort_order';
WHEN 'phase' THEN RETURN 'phase_sort_order';
WHEN 'members' THEN RETURN 'member_sort_order';
ELSE RETURN 'sort_order'; -- fallback to general sort_order
END CASE;
END;
$$;
-- Updated bulk sort order function to handle different sort columns
CREATE OR REPLACE FUNCTION update_task_sort_orders_bulk(_updates json, _group_by text DEFAULT 'status') RETURNS void
LANGUAGE plpgsql
AS
$$
DECLARE
_update_record RECORD;
_sort_column TEXT;
_sql TEXT;
BEGIN
-- Get the appropriate sort column based on grouping
_sort_column := get_sort_column_name(_group_by);
-- Simple approach: update each task's sort_order from the provided array
FOR _update_record IN
SELECT
(item->>'task_id')::uuid as task_id,
(item->>'sort_order')::int as sort_order,
(item->>'status_id')::uuid as status_id,
(item->>'priority_id')::uuid as priority_id,
(item->>'phase_id')::uuid as phase_id
FROM json_array_elements(_updates) as item
LOOP
-- Update the appropriate sort column and other fields using dynamic SQL
-- Only update sort_order if we're using the default sorting
IF _sort_column = 'sort_order' THEN
UPDATE tasks SET
sort_order = _update_record.sort_order,
status_id = COALESCE(_update_record.status_id, status_id),
priority_id = COALESCE(_update_record.priority_id, priority_id)
WHERE id = _update_record.task_id;
ELSE
-- Update only the grouping-specific sort column, not the main sort_order
_sql := 'UPDATE tasks SET ' || _sort_column || ' = $1, ' ||
'status_id = COALESCE($2, status_id), ' ||
'priority_id = COALESCE($3, priority_id) ' ||
'WHERE id = $4';
EXECUTE _sql USING
_update_record.sort_order,
_update_record.status_id,
_update_record.priority_id,
_update_record.task_id;
END IF;
-- Handle phase updates separately since it's in a different table
IF _update_record.phase_id IS NOT NULL THEN
INSERT INTO task_phase (task_id, phase_id)
VALUES (_update_record.task_id, _update_record.phase_id)
ON CONFLICT (task_id) DO UPDATE SET phase_id = _update_record.phase_id;
END IF;
END LOOP;
END;
$$;
-- Updated main sort order change handler
CREATE OR REPLACE FUNCTION handle_task_list_sort_order_change(_body json) RETURNS void
LANGUAGE plpgsql
AS
$$
DECLARE
_from_index INT;
_to_index INT;
_task_id UUID;
_project_id UUID;
_from_group UUID;
_to_group UUID;
_group_by TEXT;
_batch_size INT := 100;
_sort_column TEXT;
_sql TEXT;
BEGIN
_project_id = (_body ->> 'project_id')::UUID;
_task_id = (_body ->> 'task_id')::UUID;
_from_index = (_body ->> 'from_index')::INT;
_to_index = (_body ->> 'to_index')::INT;
_from_group = (_body ->> 'from_group')::UUID;
_to_group = (_body ->> 'to_group')::UUID;
_group_by = (_body ->> 'group_by')::TEXT;
-- Get the appropriate sort column
_sort_column := get_sort_column_name(_group_by);
-- Handle group changes
IF (_from_group <> _to_group OR (_from_group <> _to_group) IS NULL) THEN
IF (_group_by = 'status') THEN
UPDATE tasks
SET status_id = _to_group
WHERE id = _task_id
AND status_id = _from_group
AND project_id = _project_id;
END IF;
IF (_group_by = 'priority') THEN
UPDATE tasks
SET priority_id = _to_group
WHERE id = _task_id
AND priority_id = _from_group
AND project_id = _project_id;
END IF;
IF (_group_by = 'phase') THEN
IF (is_null_or_empty(_to_group) IS FALSE) THEN
INSERT INTO task_phase (task_id, phase_id)
VALUES (_task_id, _to_group)
ON CONFLICT (task_id) DO UPDATE SET phase_id = _to_group;
ELSE
DELETE FROM task_phase WHERE task_id = _task_id;
END IF;
END IF;
END IF;
-- Handle sort order changes using dynamic SQL
IF (_from_index <> _to_index) THEN
-- For the main sort_order column, we need to be careful about unique constraints
IF _sort_column = 'sort_order' THEN
-- Use a transaction-safe approach for the main sort_order column
IF (_to_index > _from_index) THEN
-- Moving down: decrease sort_order for items between old and new position
UPDATE tasks SET sort_order = sort_order - 1
WHERE project_id = _project_id
AND sort_order > _from_index
AND sort_order <= _to_index;
ELSE
-- Moving up: increase sort_order for items between new and old position
UPDATE tasks SET sort_order = sort_order + 1
WHERE project_id = _project_id
AND sort_order >= _to_index
AND sort_order < _from_index;
END IF;
-- Set the new sort_order for the moved task
UPDATE tasks SET sort_order = _to_index WHERE id = _task_id;
ELSE
-- For grouping-specific columns, use dynamic SQL since there's no unique constraint
IF (_to_index > _from_index) THEN
-- Moving down: decrease sort_order for items between old and new position
_sql := 'UPDATE tasks SET ' || _sort_column || ' = ' || _sort_column || ' - 1 ' ||
'WHERE project_id = $1 AND ' || _sort_column || ' > $2 AND ' || _sort_column || ' <= $3';
EXECUTE _sql USING _project_id, _from_index, _to_index;
ELSE
-- Moving up: increase sort_order for items between new and old position
_sql := 'UPDATE tasks SET ' || _sort_column || ' = ' || _sort_column || ' + 1 ' ||
'WHERE project_id = $1 AND ' || _sort_column || ' >= $2 AND ' || _sort_column || ' < $3';
EXECUTE _sql USING _project_id, _to_index, _from_index;
END IF;
-- Set the new sort_order for the moved task
_sql := 'UPDATE tasks SET ' || _sort_column || ' = $1 WHERE id = $2';
EXECUTE _sql USING _to_index, _task_id;
END IF;
END IF;
END;
$$;

View File

@@ -0,0 +1,179 @@
-- Migration: Fix sort order constraint violations
-- First, let's ensure all existing tasks have unique sort_order values within each project
-- This is a one-time fix to ensure data consistency
DO $$
DECLARE
_project RECORD;
_task RECORD;
_counter INTEGER;
BEGIN
-- For each project, reassign sort_order values to ensure uniqueness
FOR _project IN
SELECT DISTINCT project_id
FROM tasks
WHERE project_id IS NOT NULL
LOOP
_counter := 0;
-- Reassign sort_order values sequentially for this project
FOR _task IN
SELECT id
FROM tasks
WHERE project_id = _project.project_id
ORDER BY sort_order, created_at
LOOP
UPDATE tasks
SET sort_order = _counter
WHERE id = _task.id;
_counter := _counter + 1;
END LOOP;
END LOOP;
END
$$;
-- Now create a better version of our functions that properly handles the constraints
-- Updated bulk sort order function that avoids sort_order conflicts
CREATE OR REPLACE FUNCTION update_task_sort_orders_bulk(_updates json, _group_by text DEFAULT 'status') RETURNS void
LANGUAGE plpgsql
AS
$$
DECLARE
_update_record RECORD;
_sort_column TEXT;
_sql TEXT;
BEGIN
-- Get the appropriate sort column based on grouping
_sort_column := get_sort_column_name(_group_by);
-- Process each update record
FOR _update_record IN
SELECT
(item->>'task_id')::uuid as task_id,
(item->>'sort_order')::int as sort_order,
(item->>'status_id')::uuid as status_id,
(item->>'priority_id')::uuid as priority_id,
(item->>'phase_id')::uuid as phase_id
FROM json_array_elements(_updates) as item
LOOP
-- Update the grouping-specific sort column and other fields
_sql := 'UPDATE tasks SET ' || _sort_column || ' = $1, ' ||
'status_id = COALESCE($2, status_id), ' ||
'priority_id = COALESCE($3, priority_id), ' ||
'updated_at = CURRENT_TIMESTAMP ' ||
'WHERE id = $4';
EXECUTE _sql USING
_update_record.sort_order,
_update_record.status_id,
_update_record.priority_id,
_update_record.task_id;
-- Handle phase updates separately since it's in a different table
IF _update_record.phase_id IS NOT NULL THEN
INSERT INTO task_phase (task_id, phase_id)
VALUES (_update_record.task_id, _update_record.phase_id)
ON CONFLICT (task_id) DO UPDATE SET phase_id = _update_record.phase_id;
END IF;
END LOOP;
END;
$$;
-- Also update the helper function to be more explicit
CREATE OR REPLACE FUNCTION get_sort_column_name(_group_by TEXT) RETURNS TEXT
LANGUAGE plpgsql
AS
$$
BEGIN
CASE _group_by
WHEN 'status' THEN RETURN 'status_sort_order';
WHEN 'priority' THEN RETURN 'priority_sort_order';
WHEN 'phase' THEN RETURN 'phase_sort_order';
WHEN 'members' THEN RETURN 'member_sort_order';
-- For backward compatibility, still support general sort_order but be explicit
WHEN 'general' THEN RETURN 'sort_order';
ELSE RETURN 'status_sort_order'; -- Default to status sorting
END CASE;
END;
$$;
-- Updated main sort order change handler that avoids conflicts
CREATE OR REPLACE FUNCTION handle_task_list_sort_order_change(_body json) RETURNS void
LANGUAGE plpgsql
AS
$$
DECLARE
_from_index INT;
_to_index INT;
_task_id UUID;
_project_id UUID;
_from_group UUID;
_to_group UUID;
_group_by TEXT;
_sort_column TEXT;
_sql TEXT;
BEGIN
_project_id = (_body ->> 'project_id')::UUID;
_task_id = (_body ->> 'task_id')::UUID;
_from_index = (_body ->> 'from_index')::INT;
_to_index = (_body ->> 'to_index')::INT;
_from_group = (_body ->> 'from_group')::UUID;
_to_group = (_body ->> 'to_group')::UUID;
_group_by = (_body ->> 'group_by')::TEXT;
-- Get the appropriate sort column
_sort_column := get_sort_column_name(_group_by);
-- Handle group changes first
IF (_from_group <> _to_group OR (_from_group <> _to_group) IS NULL) THEN
IF (_group_by = 'status') THEN
UPDATE tasks
SET status_id = _to_group, updated_at = CURRENT_TIMESTAMP
WHERE id = _task_id
AND project_id = _project_id;
END IF;
IF (_group_by = 'priority') THEN
UPDATE tasks
SET priority_id = _to_group, updated_at = CURRENT_TIMESTAMP
WHERE id = _task_id
AND project_id = _project_id;
END IF;
IF (_group_by = 'phase') THEN
IF (is_null_or_empty(_to_group) IS FALSE) THEN
INSERT INTO task_phase (task_id, phase_id)
VALUES (_task_id, _to_group)
ON CONFLICT (task_id) DO UPDATE SET phase_id = _to_group;
ELSE
DELETE FROM task_phase WHERE task_id = _task_id;
END IF;
END IF;
END IF;
-- Handle sort order changes for the grouping-specific column only
IF (_from_index <> _to_index) THEN
-- Update the grouping-specific sort order (no unique constraint issues)
IF (_to_index > _from_index) THEN
-- Moving down: decrease sort order for items between old and new position
_sql := 'UPDATE tasks SET ' || _sort_column || ' = ' || _sort_column || ' - 1, ' ||
'updated_at = CURRENT_TIMESTAMP ' ||
'WHERE project_id = $1 AND ' || _sort_column || ' > $2 AND ' || _sort_column || ' <= $3';
EXECUTE _sql USING _project_id, _from_index, _to_index;
ELSE
-- Moving up: increase sort order for items between new and old position
_sql := 'UPDATE tasks SET ' || _sort_column || ' = ' || _sort_column || ' + 1, ' ||
'updated_at = CURRENT_TIMESTAMP ' ||
'WHERE project_id = $1 AND ' || _sort_column || ' >= $2 AND ' || _sort_column || ' < $3';
EXECUTE _sql USING _project_id, _to_index, _from_index;
END IF;
-- Set the new sort order for the moved task
_sql := 'UPDATE tasks SET ' || _sort_column || ' = $1, updated_at = CURRENT_TIMESTAMP WHERE id = $2';
EXECUTE _sql USING _to_index, _task_id;
END IF;
END;
$$;

View File

@@ -4313,6 +4313,24 @@ BEGIN
END END
$$; $$;
-- Helper function to get the appropriate sort column name based on grouping type
CREATE OR REPLACE FUNCTION get_sort_column_name(_group_by TEXT) RETURNS TEXT
LANGUAGE plpgsql
AS
$$
BEGIN
CASE _group_by
WHEN 'status' THEN RETURN 'status_sort_order';
WHEN 'priority' THEN RETURN 'priority_sort_order';
WHEN 'phase' THEN RETURN 'phase_sort_order';
WHEN 'members' THEN RETURN 'member_sort_order';
-- For backward compatibility, still support general sort_order but be explicit
WHEN 'general' THEN RETURN 'sort_order';
ELSE RETURN 'status_sort_order'; -- Default to status sorting
END CASE;
END;
$$;
CREATE OR REPLACE FUNCTION handle_task_list_sort_order_change(_body json) RETURNS void CREATE OR REPLACE FUNCTION handle_task_list_sort_order_change(_body json) RETURNS void
LANGUAGE plpgsql LANGUAGE plpgsql
AS AS
@@ -4325,66 +4343,67 @@ DECLARE
_from_group UUID; _from_group UUID;
_to_group UUID; _to_group UUID;
_group_by TEXT; _group_by TEXT;
_batch_size INT := 100; -- PERFORMANCE OPTIMIZATION: Batch size for large updates _sort_column TEXT;
_sql TEXT;
BEGIN BEGIN
_project_id = (_body ->> 'project_id')::UUID; _project_id = (_body ->> 'project_id')::UUID;
_task_id = (_body ->> 'task_id')::UUID; _task_id = (_body ->> 'task_id')::UUID;
_from_index = (_body ->> 'from_index')::INT;
_from_index = (_body ->> 'from_index')::INT; -- from sort_order _to_index = (_body ->> 'to_index')::INT;
_to_index = (_body ->> 'to_index')::INT; -- to sort_order
_from_group = (_body ->> 'from_group')::UUID; _from_group = (_body ->> 'from_group')::UUID;
_to_group = (_body ->> 'to_group')::UUID; _to_group = (_body ->> 'to_group')::UUID;
_group_by = (_body ->> 'group_by')::TEXT; _group_by = (_body ->> 'group_by')::TEXT;
-- PERFORMANCE OPTIMIZATION: Use CTE for better query planning -- Get the appropriate sort column
IF (_from_group <> _to_group OR (_from_group <> _to_group) IS NULL) _sort_column := get_sort_column_name(_group_by);
THEN
-- PERFORMANCE OPTIMIZATION: Batch update group changes -- Handle group changes first
IF (_group_by = 'status') IF (_from_group <> _to_group OR (_from_group <> _to_group) IS NULL) THEN
THEN IF (_group_by = 'status') THEN
UPDATE tasks UPDATE tasks
SET status_id = _to_group SET status_id = _to_group, updated_at = CURRENT_TIMESTAMP
WHERE id = _task_id WHERE id = _task_id
AND status_id = _from_group
AND project_id = _project_id; AND project_id = _project_id;
END IF; END IF;
IF (_group_by = 'priority') IF (_group_by = 'priority') THEN
THEN
UPDATE tasks UPDATE tasks
SET priority_id = _to_group SET priority_id = _to_group, updated_at = CURRENT_TIMESTAMP
WHERE id = _task_id WHERE id = _task_id
AND priority_id = _from_group
AND project_id = _project_id; AND project_id = _project_id;
END IF; END IF;
IF (_group_by = 'phase') IF (_group_by = 'phase') THEN
THEN IF (is_null_or_empty(_to_group) IS FALSE) THEN
IF (is_null_or_empty(_to_group) IS FALSE)
THEN
INSERT INTO task_phase (task_id, phase_id) INSERT INTO task_phase (task_id, phase_id)
VALUES (_task_id, _to_group) VALUES (_task_id, _to_group)
ON CONFLICT (task_id) DO UPDATE SET phase_id = _to_group; ON CONFLICT (task_id) DO UPDATE SET phase_id = _to_group;
ELSE
DELETE FROM task_phase WHERE task_id = _task_id;
END IF; END IF;
IF (is_null_or_empty(_to_group) IS TRUE)
THEN
DELETE
FROM task_phase
WHERE task_id = _task_id;
END IF; END IF;
END IF; END IF;
-- PERFORMANCE OPTIMIZATION: Optimized sort order handling -- Handle sort order changes for the grouping-specific column only
IF ((_body ->> 'to_last_index')::BOOLEAN IS TRUE AND _from_index < _to_index) IF (_from_index <> _to_index) THEN
THEN -- Update the grouping-specific sort order (no unique constraint issues)
PERFORM handle_task_list_sort_inside_group_optimized(_from_index, _to_index, _task_id, _project_id, _batch_size); IF (_to_index > _from_index) THEN
-- Moving down: decrease sort order for items between old and new position
_sql := 'UPDATE tasks SET ' || _sort_column || ' = ' || _sort_column || ' - 1, ' ||
'updated_at = CURRENT_TIMESTAMP ' ||
'WHERE project_id = $1 AND ' || _sort_column || ' > $2 AND ' || _sort_column || ' <= $3';
EXECUTE _sql USING _project_id, _from_index, _to_index;
ELSE ELSE
PERFORM handle_task_list_sort_between_groups_optimized(_from_index, _to_index, _task_id, _project_id, _batch_size); -- Moving up: increase sort order for items between new and old position
_sql := 'UPDATE tasks SET ' || _sort_column || ' = ' || _sort_column || ' + 1, ' ||
'updated_at = CURRENT_TIMESTAMP ' ||
'WHERE project_id = $1 AND ' || _sort_column || ' >= $2 AND ' || _sort_column || ' < $3';
EXECUTE _sql USING _project_id, _to_index, _from_index;
END IF; END IF;
ELSE
PERFORM handle_task_list_sort_inside_group_optimized(_from_index, _to_index, _task_id, _project_id, _batch_size); -- Set the new sort order for the moved task
_sql := 'UPDATE tasks SET ' || _sort_column || ' = $1, updated_at = CURRENT_TIMESTAMP WHERE id = $2';
EXECUTE _sql USING _to_index, _task_id;
END IF; END IF;
END END
$$; $$;
@@ -6521,15 +6540,20 @@ BEGIN
END END
$$; $$;
-- Simple function to update task sort orders in bulk -- Updated bulk sort order function that avoids sort_order conflicts
CREATE OR REPLACE FUNCTION update_task_sort_orders_bulk(_updates json) RETURNS void CREATE OR REPLACE FUNCTION update_task_sort_orders_bulk(_updates json, _group_by text DEFAULT 'status') RETURNS void
LANGUAGE plpgsql LANGUAGE plpgsql
AS AS
$$ $$
DECLARE DECLARE
_update_record RECORD; _update_record RECORD;
_sort_column TEXT;
_sql TEXT;
BEGIN BEGIN
-- Simple approach: update each task's sort_order from the provided array -- Get the appropriate sort column based on grouping
_sort_column := get_sort_column_name(_group_by);
-- Process each update record
FOR _update_record IN FOR _update_record IN
SELECT SELECT
(item->>'task_id')::uuid as task_id, (item->>'task_id')::uuid as task_id,
@@ -6539,12 +6563,18 @@ BEGIN
(item->>'phase_id')::uuid as phase_id (item->>'phase_id')::uuid as phase_id
FROM json_array_elements(_updates) as item FROM json_array_elements(_updates) as item
LOOP LOOP
UPDATE tasks -- Update the grouping-specific sort column and other fields
SET _sql := 'UPDATE tasks SET ' || _sort_column || ' = $1, ' ||
sort_order = _update_record.sort_order, 'status_id = COALESCE($2, status_id), ' ||
status_id = COALESCE(_update_record.status_id, status_id), 'priority_id = COALESCE($3, priority_id), ' ||
priority_id = COALESCE(_update_record.priority_id, priority_id) 'updated_at = CURRENT_TIMESTAMP ' ||
WHERE id = _update_record.task_id; 'WHERE id = $4';
EXECUTE _sql USING
_update_record.sort_order,
_update_record.status_id,
_update_record.priority_id,
_update_record.task_id;
-- Handle phase updates separately since it's in a different table -- Handle phase updates separately since it's in a different table
IF _update_record.phase_id IS NOT NULL THEN IF _update_record.phase_id IS NOT NULL THEN

View File

@@ -53,11 +53,30 @@ function notifyStatusChange(socket: Socket, config: Config) {
} }
async function emitSortOrderChange(data: ChangeRequest, socket: Socket) { async function emitSortOrderChange(data: ChangeRequest, socket: Socket) {
// Determine which sort column to use based on group_by
let sortColumn = 'sort_order';
switch (data.group_by) {
case 'status':
sortColumn = 'status_sort_order';
break;
case 'priority':
sortColumn = 'priority_sort_order';
break;
case 'phase':
sortColumn = 'phase_sort_order';
break;
case 'members':
sortColumn = 'member_sort_order';
break;
default:
sortColumn = 'sort_order';
}
const q = ` const q = `
SELECT id, sort_order, completed_at SELECT id, sort_order, ${sortColumn} as current_sort_order, completed_at
FROM tasks FROM tasks
WHERE project_id = $1 WHERE project_id = $1
ORDER BY sort_order; ORDER BY ${sortColumn};
`; `;
const tasks = await db.query(q, [data.project_id]); const tasks = await db.query(q, [data.project_id]);
socket.emit(SocketEvents.TASK_SORT_ORDER_CHANGE.toString(), tasks.rows); socket.emit(SocketEvents.TASK_SORT_ORDER_CHANGE.toString(), tasks.rows);
@@ -84,9 +103,9 @@ export async function on_task_sort_order_change(_io: Server, socket: Socket, dat
} }
} }
// Use the simple bulk update function // Use the simple bulk update function with group_by parameter
const q = `SELECT update_task_sort_orders_bulk($1);`; const q = `SELECT update_task_sort_orders_bulk($1, $2);`;
await db.query(q, [JSON.stringify(data.task_updates)]); await db.query(q, [JSON.stringify(data.task_updates), data.group_by || 'status']);
await emitSortOrderChange(data, socket); await emitSortOrderChange(data, socket);
// Handle notifications and logging // Handle notifications and logging

View File

@@ -1,13 +1,84 @@
import { useState, useCallback } from 'react'; import { useState, useCallback } from 'react';
import { DragEndEvent, DragOverEvent, DragStartEvent } from '@dnd-kit/core'; import { DragEndEvent, DragOverEvent, DragStartEvent } from '@dnd-kit/core';
import { useAppDispatch } from '@/hooks/useAppDispatch'; import { useAppDispatch } from '@/hooks/useAppDispatch';
import { reorderTasksInGroup, moveTaskBetweenGroups } from '@/features/task-management/task-management.slice'; import { useAppSelector } from '@/hooks/useAppSelector';
import { Task, TaskGroup } from '@/types/task-management.types'; import { reorderTasksInGroup } from '@/features/task-management/task-management.slice';
import { selectCurrentGrouping } from '@/features/task-management/grouping.slice';
import { Task, TaskGroup, getSortOrderField } from '@/types/task-management.types';
import { useSocket } from '@/socket/socketContext';
import { SocketEvents } from '@/shared/socket-events';
import { useParams } from 'react-router-dom';
import { useAuthService } from '@/hooks/useAuth';
export const useDragAndDrop = (allTasks: Task[], groups: TaskGroup[]) => { export const useDragAndDrop = (allTasks: Task[], groups: TaskGroup[]) => {
const dispatch = useAppDispatch(); const dispatch = useAppDispatch();
const { socket, connected } = useSocket();
const { projectId } = useParams();
const currentGrouping = useAppSelector(selectCurrentGrouping);
const currentSession = useAuthService().getCurrentSession();
const [activeId, setActiveId] = useState<string | null>(null); const [activeId, setActiveId] = useState<string | null>(null);
// Helper function to emit socket event for persistence
const emitTaskSortChange = useCallback(
(taskId: string, sourceGroup: TaskGroup, targetGroup: TaskGroup, insertIndex: number) => {
if (!socket || !connected || !projectId) {
console.warn('Socket not connected or missing project ID');
return;
}
const task = allTasks.find(t => t.id === taskId);
if (!task) {
console.error('Task not found for socket emission:', taskId);
return;
}
// Get team_id from current session
const teamId = currentSession?.team_id || '';
// Calculate sort orders for socket emission using the appropriate sort field
const sortField = getSortOrderField(currentGrouping);
const fromIndex = (task as any)[sortField] || task.order || 0;
let toIndex = 0;
let toLastIndex = false;
if (targetGroup.taskIds.length === 0) {
toIndex = 0;
toLastIndex = true;
} else if (insertIndex >= targetGroup.taskIds.length) {
// Dropping at the end
const lastTask = allTasks.find(t => t.id === targetGroup.taskIds[targetGroup.taskIds.length - 1]);
toIndex = ((lastTask as any)?.[sortField] || lastTask?.order || 0) + 1;
toLastIndex = true;
} else {
// Dropping at specific position
const targetTask = allTasks.find(t => t.id === targetGroup.taskIds[insertIndex]);
toIndex = (targetTask as any)?.[sortField] || targetTask?.order || insertIndex;
toLastIndex = false;
}
const socketData = {
project_id: projectId,
from_index: fromIndex,
to_index: toIndex,
to_last_index: toLastIndex,
from_group: sourceGroup.id,
to_group: targetGroup.id,
group_by: currentGrouping || 'status',
task: {
id: task.id,
project_id: projectId,
status: task.status || '',
priority: task.priority || '',
},
team_id: teamId,
};
console.log('Emitting TASK_SORT_ORDER_CHANGE:', socketData);
socket.emit(SocketEvents.TASK_SORT_ORDER_CHANGE.toString(), socketData);
},
[socket, connected, projectId, allTasks, currentGrouping, currentSession]
);
const handleDragStart = useCallback((event: DragStartEvent) => { const handleDragStart = useCallback((event: DragStartEvent) => {
setActiveId(event.active.id as string); setActiveId(event.active.id as string);
}, []); }, []);
@@ -124,16 +195,8 @@ export const useDragAndDrop = (allTasks: Task[], groups: TaskGroup[]) => {
newPosition: insertIndex, newPosition: insertIndex,
}); });
// Move task to the target group // reorderTasksInGroup handles both same-group and cross-group moves
dispatch( // No need for separate moveTaskBetweenGroups call
moveTaskBetweenGroups({
taskId: activeId as string,
sourceGroupId: activeGroup.id,
targetGroupId: targetGroup.id,
})
);
// Reorder task within target group at drop position
dispatch( dispatch(
reorderTasksInGroup({ reorderTasksInGroup({
sourceTaskId: activeId as string, sourceTaskId: activeId as string,
@@ -142,6 +205,9 @@ export const useDragAndDrop = (allTasks: Task[], groups: TaskGroup[]) => {
destinationGroupId: targetGroup.id, destinationGroupId: targetGroup.id,
}) })
); );
// Emit socket event for persistence
emitTaskSortChange(activeId as string, activeGroup, targetGroup, insertIndex);
} else { } else {
// Reordering within the same group // Reordering within the same group
console.log('Reordering task within same group:', { console.log('Reordering task within same group:', {
@@ -161,10 +227,13 @@ export const useDragAndDrop = (allTasks: Task[], groups: TaskGroup[]) => {
destinationGroupId: activeGroup.id, destinationGroupId: activeGroup.id,
}) })
); );
// Emit socket event for persistence
emitTaskSortChange(activeId as string, activeGroup, targetGroup, insertIndex);
} }
} }
}, },
[allTasks, groups, dispatch] [allTasks, groups, dispatch, emitTaskSortChange]
); );
return { return {

View File

@@ -7,7 +7,7 @@ import {
EntityId, EntityId,
createSelector, createSelector,
} from '@reduxjs/toolkit'; } from '@reduxjs/toolkit';
import { Task, TaskManagementState, TaskGroup, TaskGrouping } from '@/types/task-management.types'; import { Task, TaskManagementState, TaskGroup, TaskGrouping, getSortOrderField } from '@/types/task-management.types';
import { ITaskListColumn } from '@/types/tasks/taskList.types'; import { ITaskListColumn } from '@/types/tasks/taskList.types';
import { RootState } from '@/app/store'; import { RootState } from '@/app/store';
import { import {
@@ -661,11 +661,11 @@ const taskManagementSlice = createSlice({
newTasks.splice(newTasks.indexOf(destinationTaskId), 0, removed); newTasks.splice(newTasks.indexOf(destinationTaskId), 0, removed);
group.taskIds = newTasks; group.taskIds = newTasks;
// Update order for affected tasks. Assuming simple reordering affects order. // Update order for affected tasks using the appropriate sort field
// This might need more sophisticated logic based on how `order` is used. const sortField = getSortOrderField(state.grouping?.id);
newTasks.forEach((id, index) => { newTasks.forEach((id, index) => {
if (newEntities[id]) { if (newEntities[id]) {
newEntities[id] = { ...newEntities[id], order: index }; newEntities[id] = { ...newEntities[id], [sortField]: index };
} }
}); });
} }
@@ -723,12 +723,13 @@ const taskManagementSlice = createSlice({
newEntities[sourceTaskId] = updatedTask; newEntities[sourceTaskId] = updatedTask;
} }
// Update order for affected tasks in both groups if necessary // Update order for affected tasks in both groups using the appropriate sort field
const sortField = getSortOrderField(state.grouping?.id);
sourceGroup.taskIds.forEach((id, index) => { sourceGroup.taskIds.forEach((id, index) => {
if (newEntities[id]) newEntities[id] = { ...newEntities[id], order: index }; if (newEntities[id]) newEntities[id] = { ...newEntities[id], [sortField]: index };
}); });
destinationGroup.taskIds.forEach((id, index) => { destinationGroup.taskIds.forEach((id, index) => {
if (newEntities[id]) newEntities[id] = { ...newEntities[id], order: index }; if (newEntities[id]) newEntities[id] = { ...newEntities[id], [sortField]: index };
}); });
} }
} }

View File

@@ -41,6 +41,10 @@ export interface Task {
has_subscribers?: boolean; has_subscribers?: boolean;
schedule_id?: string | null; schedule_id?: string | null;
order?: number; order?: number;
status_sort_order?: number; // Sort order when grouped by status
priority_sort_order?: number; // Sort order when grouped by priority
phase_sort_order?: number; // Sort order when grouped by phase
member_sort_order?: number; // Sort order when grouped by members
reporter?: string; // Reporter field reporter?: string; // Reporter field
timeTracking?: { // Time tracking information timeTracking?: { // Time tracking information
logged?: number; logged?: number;
@@ -173,3 +177,21 @@ export interface BulkAction {
value?: any; value?: any;
taskIds: string[]; taskIds: string[];
} }
// Helper function to get the appropriate sort order field based on grouping
export function getSortOrderField(grouping: string | undefined): keyof Task {
switch (grouping) {
case 'status':
return 'status_sort_order';
case 'priority':
return 'priority_sort_order';
case 'phase':
return 'phase_sort_order';
case 'members':
return 'member_sort_order';
case 'general':
return 'order'; // explicit general sorting
default:
return 'status_sort_order'; // Default to status sorting to match backend
}
}