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

@@ -4313,6 +4313,24 @@ BEGIN
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
LANGUAGE plpgsql
AS
@@ -4325,66 +4343,67 @@ DECLARE
_from_group UUID;
_to_group UUID;
_group_by TEXT;
_batch_size INT := 100; -- PERFORMANCE OPTIMIZATION: Batch size for large updates
_sort_column TEXT;
_sql TEXT;
BEGIN
_project_id = (_body ->> 'project_id')::UUID;
_task_id = (_body ->> 'task_id')::UUID;
_from_index = (_body ->> 'from_index')::INT; -- from sort_order
_to_index = (_body ->> 'to_index')::INT; -- to sort_order
_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;
-- PERFORMANCE OPTIMIZATION: Use CTE for better query planning
IF (_from_group <> _to_group OR (_from_group <> _to_group) IS NULL)
THEN
-- PERFORMANCE OPTIMIZATION: Batch update group changes
IF (_group_by = 'status')
THEN
-- 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
SET status_id = _to_group, updated_at = CURRENT_TIMESTAMP
WHERE id = _task_id
AND status_id = _from_group
AND project_id = _project_id;
END IF;
IF (_group_by = 'priority')
THEN
IF (_group_by = 'priority') THEN
UPDATE tasks
SET priority_id = _to_group
SET priority_id = _to_group, updated_at = CURRENT_TIMESTAMP
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
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;
END IF;
IF (is_null_or_empty(_to_group) IS TRUE)
THEN
DELETE
FROM task_phase
WHERE task_id = _task_id;
ELSE
DELETE FROM task_phase WHERE task_id = _task_id;
END IF;
END IF;
END IF;
-- PERFORMANCE OPTIMIZATION: Optimized sort order handling
IF ((_body ->> 'to_last_index')::BOOLEAN IS TRUE AND _from_index < _to_index)
THEN
PERFORM handle_task_list_sort_inside_group_optimized(_from_index, _to_index, _task_id, _project_id, _batch_size);
-- 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
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;
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
$$;
@@ -6521,15 +6540,20 @@ BEGIN
END
$$;
-- Simple function to update task sort orders in bulk
CREATE OR REPLACE FUNCTION update_task_sort_orders_bulk(_updates json) RETURNS void
-- 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
-- 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
SELECT
(item->>'task_id')::uuid as task_id,
@@ -6539,12 +6563,18 @@ BEGIN
(item->>'phase_id')::uuid as phase_id
FROM json_array_elements(_updates) as item
LOOP
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;
-- 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