refactor(sort-orders): remove outdated deployment and implementation guides

- Deleted the `DEPLOYMENT_GUIDE_SORT_ORDERS.md` and `SEPARATE_SORT_ORDERS_IMPLEMENTATION.md` files as they are no longer relevant following the recent updates to the sort orders feature.
- Introduced new migration scripts to address duplicate sort orders and ensure data integrity across the updated task sorting system.
- Updated database schema to include new sort order columns and constraints for improved performance and organization.
- Enhanced backend functions and frontend components to support the new sorting logic and maintain user experience during task organization.
This commit is contained in:
chamikaJ
2025-07-15 13:18:51 +05:30
parent 407dc416ec
commit 6d8c475e67
22 changed files with 718 additions and 450 deletions

View File

@@ -0,0 +1,300 @@
-- Fix Duplicate Sort Orders Script
-- This script detects and fixes duplicate sort order values that break task ordering
-- 1. DETECTION QUERIES - Run these first to see the scope of the problem
-- Check for duplicates in main sort_order column
SELECT
project_id,
sort_order,
COUNT(*) as duplicate_count,
STRING_AGG(id::text, ', ') as task_ids
FROM tasks
WHERE project_id IS NOT NULL
GROUP BY project_id, sort_order
HAVING COUNT(*) > 1
ORDER BY project_id, sort_order;
-- Check for duplicates in status_sort_order
SELECT
project_id,
status_sort_order,
COUNT(*) as duplicate_count,
STRING_AGG(id::text, ', ') as task_ids
FROM tasks
WHERE project_id IS NOT NULL
GROUP BY project_id, status_sort_order
HAVING COUNT(*) > 1
ORDER BY project_id, status_sort_order;
-- Check for duplicates in priority_sort_order
SELECT
project_id,
priority_sort_order,
COUNT(*) as duplicate_count,
STRING_AGG(id::text, ', ') as task_ids
FROM tasks
WHERE project_id IS NOT NULL
GROUP BY project_id, priority_sort_order
HAVING COUNT(*) > 1
ORDER BY project_id, priority_sort_order;
-- Check for duplicates in phase_sort_order
SELECT
project_id,
phase_sort_order,
COUNT(*) as duplicate_count,
STRING_AGG(id::text, ', ') as task_ids
FROM tasks
WHERE project_id IS NOT NULL
GROUP BY project_id, phase_sort_order
HAVING COUNT(*) > 1
ORDER BY project_id, phase_sort_order;
-- Note: member_sort_order removed - no longer used
-- 2. CLEANUP FUNCTIONS
-- Fix duplicates in main sort_order column
CREATE OR REPLACE FUNCTION fix_sort_order_duplicates() RETURNS void
LANGUAGE plpgsql
AS
$$
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;
RAISE NOTICE 'Fixed sort_order duplicates for all projects';
END
$$;
-- Fix duplicates in status_sort_order column
CREATE OR REPLACE FUNCTION fix_status_sort_order_duplicates() RETURNS void
LANGUAGE plpgsql
AS
$$
DECLARE
_project RECORD;
_task RECORD;
_counter INTEGER;
BEGIN
FOR _project IN
SELECT DISTINCT project_id
FROM tasks
WHERE project_id IS NOT NULL
LOOP
_counter := 0;
FOR _task IN
SELECT id
FROM tasks
WHERE project_id = _project.project_id
ORDER BY status_sort_order, created_at
LOOP
UPDATE tasks
SET status_sort_order = _counter
WHERE id = _task.id;
_counter := _counter + 1;
END LOOP;
END LOOP;
RAISE NOTICE 'Fixed status_sort_order duplicates for all projects';
END
$$;
-- Fix duplicates in priority_sort_order column
CREATE OR REPLACE FUNCTION fix_priority_sort_order_duplicates() RETURNS void
LANGUAGE plpgsql
AS
$$
DECLARE
_project RECORD;
_task RECORD;
_counter INTEGER;
BEGIN
FOR _project IN
SELECT DISTINCT project_id
FROM tasks
WHERE project_id IS NOT NULL
LOOP
_counter := 0;
FOR _task IN
SELECT id
FROM tasks
WHERE project_id = _project.project_id
ORDER BY priority_sort_order, created_at
LOOP
UPDATE tasks
SET priority_sort_order = _counter
WHERE id = _task.id;
_counter := _counter + 1;
END LOOP;
END LOOP;
RAISE NOTICE 'Fixed priority_sort_order duplicates for all projects';
END
$$;
-- Fix duplicates in phase_sort_order column
CREATE OR REPLACE FUNCTION fix_phase_sort_order_duplicates() RETURNS void
LANGUAGE plpgsql
AS
$$
DECLARE
_project RECORD;
_task RECORD;
_counter INTEGER;
BEGIN
FOR _project IN
SELECT DISTINCT project_id
FROM tasks
WHERE project_id IS NOT NULL
LOOP
_counter := 0;
FOR _task IN
SELECT id
FROM tasks
WHERE project_id = _project.project_id
ORDER BY phase_sort_order, created_at
LOOP
UPDATE tasks
SET phase_sort_order = _counter
WHERE id = _task.id;
_counter := _counter + 1;
END LOOP;
END LOOP;
RAISE NOTICE 'Fixed phase_sort_order duplicates for all projects';
END
$$;
-- Note: fix_member_sort_order_duplicates() removed - no longer needed
-- Master function to fix all sort order duplicates
CREATE OR REPLACE FUNCTION fix_all_duplicate_sort_orders() RETURNS void
LANGUAGE plpgsql
AS
$$
BEGIN
RAISE NOTICE 'Starting sort order cleanup for all columns...';
PERFORM fix_sort_order_duplicates();
PERFORM fix_status_sort_order_duplicates();
PERFORM fix_priority_sort_order_duplicates();
PERFORM fix_phase_sort_order_duplicates();
RAISE NOTICE 'Completed sort order cleanup for all columns';
END
$$;
-- 3. VERIFICATION FUNCTION
-- Verify that duplicates have been fixed
CREATE OR REPLACE FUNCTION verify_sort_order_integrity() RETURNS TABLE(
column_name text,
project_id uuid,
duplicate_count bigint,
status text
)
LANGUAGE plpgsql
AS
$$
BEGIN
-- Check sort_order duplicates
RETURN QUERY
SELECT
'sort_order'::text as column_name,
t.project_id,
COUNT(*) as duplicate_count,
CASE WHEN COUNT(*) > 1 THEN 'DUPLICATES FOUND' ELSE 'OK' END as status
FROM tasks t
WHERE t.project_id IS NOT NULL
GROUP BY t.project_id, t.sort_order
HAVING COUNT(*) > 1;
-- Check status_sort_order duplicates
RETURN QUERY
SELECT
'status_sort_order'::text as column_name,
t.project_id,
COUNT(*) as duplicate_count,
CASE WHEN COUNT(*) > 1 THEN 'DUPLICATES FOUND' ELSE 'OK' END as status
FROM tasks t
WHERE t.project_id IS NOT NULL
GROUP BY t.project_id, t.status_sort_order
HAVING COUNT(*) > 1;
-- Check priority_sort_order duplicates
RETURN QUERY
SELECT
'priority_sort_order'::text as column_name,
t.project_id,
COUNT(*) as duplicate_count,
CASE WHEN COUNT(*) > 1 THEN 'DUPLICATES FOUND' ELSE 'OK' END as status
FROM tasks t
WHERE t.project_id IS NOT NULL
GROUP BY t.project_id, t.priority_sort_order
HAVING COUNT(*) > 1;
-- Check phase_sort_order duplicates
RETURN QUERY
SELECT
'phase_sort_order'::text as column_name,
t.project_id,
COUNT(*) as duplicate_count,
CASE WHEN COUNT(*) > 1 THEN 'DUPLICATES FOUND' ELSE 'OK' END as status
FROM tasks t
WHERE t.project_id IS NOT NULL
GROUP BY t.project_id, t.phase_sort_order
HAVING COUNT(*) > 1;
-- Note: member_sort_order verification removed - column no longer used
END
$$;
-- 4. USAGE INSTRUCTIONS
/*
USAGE:
1. First, run the detection queries to see which projects have duplicates
2. Then run this to fix all duplicates:
SELECT fix_all_duplicate_sort_orders();
3. Finally, verify the fix worked:
SELECT * FROM verify_sort_order_integrity();
If verification returns no rows, all duplicates have been fixed successfully.
WARNING: This will reassign sort order values based on current order + creation time.
Make sure to backup your database before running these functions.
*/

View File

@@ -1391,27 +1391,30 @@ ALTER TABLE task_work_log
CHECK (time_spent >= (0)::NUMERIC);
CREATE TABLE IF NOT EXISTS tasks (
id UUID DEFAULT uuid_generate_v4() NOT NULL,
name TEXT NOT NULL,
description TEXT,
done BOOLEAN DEFAULT FALSE NOT NULL,
total_minutes NUMERIC DEFAULT 0 NOT NULL,
archived BOOLEAN DEFAULT FALSE NOT NULL,
task_no BIGINT NOT NULL,
start_date TIMESTAMP WITH TIME ZONE,
end_date TIMESTAMP WITH TIME ZONE,
priority_id UUID NOT NULL,
project_id UUID NOT NULL,
reporter_id UUID NOT NULL,
parent_task_id UUID,
status_id UUID NOT NULL,
completed_at TIMESTAMP WITH TIME ZONE,
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP NOT NULL,
updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP NOT NULL,
sort_order INTEGER DEFAULT 0 NOT NULL,
roadmap_sort_order INTEGER DEFAULT 0 NOT NULL,
billable BOOLEAN DEFAULT TRUE,
schedule_id UUID
id UUID DEFAULT uuid_generate_v4() NOT NULL,
name TEXT NOT NULL,
description TEXT,
done BOOLEAN DEFAULT FALSE NOT NULL,
total_minutes NUMERIC DEFAULT 0 NOT NULL,
archived BOOLEAN DEFAULT FALSE NOT NULL,
task_no BIGINT NOT NULL,
start_date TIMESTAMP WITH TIME ZONE,
end_date TIMESTAMP WITH TIME ZONE,
priority_id UUID NOT NULL,
project_id UUID NOT NULL,
reporter_id UUID NOT NULL,
parent_task_id UUID,
status_id UUID NOT NULL,
completed_at TIMESTAMP WITH TIME ZONE,
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP NOT NULL,
updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP NOT NULL,
sort_order INTEGER DEFAULT 0 NOT NULL,
roadmap_sort_order INTEGER DEFAULT 0 NOT NULL,
status_sort_order INTEGER DEFAULT 0 NOT NULL,
priority_sort_order INTEGER DEFAULT 0 NOT NULL,
phase_sort_order INTEGER DEFAULT 0 NOT NULL,
billable BOOLEAN DEFAULT TRUE,
schedule_id UUID
);
ALTER TABLE tasks
@@ -1499,6 +1502,21 @@ ALTER TABLE tasks
ADD CONSTRAINT tasks_total_minutes_check
CHECK ((total_minutes >= (0)::NUMERIC) AND (total_minutes <= (999999)::NUMERIC));
-- Add constraints for new sort order columns
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);
-- Add indexes for performance on new sort order columns
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);
-- Add 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';
CREATE TABLE IF NOT EXISTS tasks_assignees (
task_id UUID NOT NULL,
project_member_id UUID NOT NULL,

View File

@@ -4608,31 +4608,31 @@ BEGIN
INSERT INTO project_task_list_cols (project_id, name, key, index, pinned)
VALUES (_project_id, 'Progress', 'PROGRESS', 3, TRUE);
INSERT INTO project_task_list_cols (project_id, name, key, index, pinned)
VALUES (_project_id, 'Members', 'ASSIGNEES', 4, TRUE);
VALUES (_project_id, 'Status', 'STATUS', 4, TRUE);
INSERT INTO project_task_list_cols (project_id, name, key, index, pinned)
VALUES (_project_id, 'Labels', 'LABELS', 5, TRUE);
VALUES (_project_id, 'Members', 'ASSIGNEES', 5, TRUE);
INSERT INTO project_task_list_cols (project_id, name, key, index, pinned)
VALUES (_project_id, 'Status', 'STATUS', 6, TRUE);
VALUES (_project_id, 'Labels', 'LABELS', 6, TRUE);
INSERT INTO project_task_list_cols (project_id, name, key, index, pinned)
VALUES (_project_id, 'Priority', 'PRIORITY', 7, TRUE);
VALUES (_project_id, 'Phase', 'PHASE', 7, TRUE);
INSERT INTO project_task_list_cols (project_id, name, key, index, pinned)
VALUES (_project_id, 'Time Tracking', 'TIME_TRACKING', 8, TRUE);
VALUES (_project_id, 'Priority', 'PRIORITY', 8, TRUE);
INSERT INTO project_task_list_cols (project_id, name, key, index, pinned)
VALUES (_project_id, 'Estimation', 'ESTIMATION', 9, FALSE);
VALUES (_project_id, 'Time Tracking', 'TIME_TRACKING', 9, TRUE);
INSERT INTO project_task_list_cols (project_id, name, key, index, pinned)
VALUES (_project_id, 'Start Date', 'START_DATE', 10, FALSE);
VALUES (_project_id, 'Estimation', 'ESTIMATION', 10, FALSE);
INSERT INTO project_task_list_cols (project_id, name, key, index, pinned)
VALUES (_project_id, 'Due Date', 'DUE_DATE', 11, TRUE);
VALUES (_project_id, 'Start Date', 'START_DATE', 11, FALSE);
INSERT INTO project_task_list_cols (project_id, name, key, index, pinned)
VALUES (_project_id, 'Completed Date', 'COMPLETED_DATE', 12, FALSE);
VALUES (_project_id, 'Due Date', 'DUE_DATE', 12, TRUE);
INSERT INTO project_task_list_cols (project_id, name, key, index, pinned)
VALUES (_project_id, 'Created Date', 'CREATED_DATE', 13, FALSE);
VALUES (_project_id, 'Completed Date', 'COMPLETED_DATE', 13, FALSE);
INSERT INTO project_task_list_cols (project_id, name, key, index, pinned)
VALUES (_project_id, 'Last Updated', 'LAST_UPDATED', 14, FALSE);
VALUES (_project_id, 'Created Date', 'CREATED_DATE', 14, FALSE);
INSERT INTO project_task_list_cols (project_id, name, key, index, pinned)
VALUES (_project_id, 'Reporter', 'REPORTER', 15, FALSE);
VALUES (_project_id, 'Last Updated', 'LAST_UPDATED', 15, FALSE);
INSERT INTO project_task_list_cols (project_id, name, key, index, pinned)
VALUES (_project_id, 'Phase', 'PHASE', 16, FALSE);
VALUES (_project_id, 'Reporter', 'REPORTER', 16, FALSE);
END
$$;
@@ -6585,3 +6585,66 @@ BEGIN
END LOOP;
END
$$;
-- 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';
-- 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 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);
-- 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;
$$;

View File

@@ -109,12 +109,29 @@ export default class TasksControllerV2 extends TasksControllerBase {
}
private static getQuery(userId: string, options: ParsedQs) {
const searchField = options.search ? ["t.name", "CONCAT((SELECT key FROM projects WHERE id = t.project_id), '-', task_no)"] : "sort_order";
// Determine which sort column to use based on grouping
const groupBy = options.group || 'status';
let defaultSortColumn = 'sort_order';
switch (groupBy) {
case 'status':
defaultSortColumn = 'status_sort_order';
break;
case 'priority':
defaultSortColumn = 'priority_sort_order';
break;
case 'phase':
defaultSortColumn = 'phase_sort_order';
break;
default:
defaultSortColumn = 'sort_order';
}
const searchField = options.search ? ["t.name", "CONCAT((SELECT key FROM projects WHERE id = t.project_id), '-', task_no)"] : defaultSortColumn;
const { searchQuery, sortField } = TasksControllerV2.toPaginationOptions(options, searchField);
const isSubTasks = !!options.parent_task;
const sortFields = sortField.replace(/ascend/g, "ASC").replace(/descend/g, "DESC") || "sort_order";
const sortFields = sortField.replace(/ascend/g, "ASC").replace(/descend/g, "DESC") || defaultSortColumn;
// Filter tasks by statuses
const statusesFilter = TasksControllerV2.getFilterByStatusWhereClosure(options.statuses as string);
@@ -196,6 +213,9 @@ export default class TasksControllerV2 extends TasksControllerBase {
t.archived,
t.description,
t.sort_order,
t.status_sort_order,
t.priority_sort_order,
t.phase_sort_order,
t.progress_value,
t.manual_progress,
t.weight,
@@ -1088,7 +1108,7 @@ export default class TasksControllerV2 extends TasksControllerBase {
custom_column_values: task.custom_column_values || {}, // Include custom column values
createdAt: task.created_at || new Date().toISOString(),
updatedAt: task.updated_at || new Date().toISOString(),
order: typeof task.sort_order === "number" ? task.sort_order : 0,
order: TasksControllerV2.getTaskSortOrder(task, groupBy),
// Additional metadata for frontend
originalStatusId: task.status,
originalPriorityId: task.priority,
@@ -1292,6 +1312,19 @@ export default class TasksControllerV2 extends TasksControllerBase {
}));
}
private static getTaskSortOrder(task: any, groupBy: string): number {
switch (groupBy) {
case GroupBy.STATUS:
return typeof task.status_sort_order === "number" ? task.status_sort_order : 0;
case GroupBy.PRIORITY:
return typeof task.priority_sort_order === "number" ? task.priority_sort_order : 0;
case GroupBy.PHASE:
return typeof task.phase_sort_order === "number" ? task.phase_sort_order : 0;
default:
return typeof task.sort_order === "number" ? task.sort_order : 0;
}
}
private static getDefaultGroupColor(groupBy: string, groupValue: string): string {
const colorMaps: Record<string, Record<string, string>> = {
[GroupBy.STATUS]: {

View File

@@ -54,22 +54,19 @@ function notifyStatusChange(socket: Socket, config: Config) {
async function emitSortOrderChange(data: ChangeRequest, socket: Socket) {
// Determine which sort column to use based on group_by
let sortColumn = 'sort_order';
let sortColumn = "sort_order";
switch (data.group_by) {
case 'status':
sortColumn = 'status_sort_order';
case "status":
sortColumn = "status_sort_order";
break;
case 'priority':
sortColumn = 'priority_sort_order';
case "priority":
sortColumn = "priority_sort_order";
break;
case 'phase':
sortColumn = 'phase_sort_order';
break;
case 'members':
sortColumn = 'member_sort_order';
case "phase":
sortColumn = "phase_sort_order";
break;
default:
sortColumn = 'sort_order';
sortColumn = "sort_order";
}
const q = `
@@ -105,7 +102,7 @@ export async function on_task_sort_order_change(_io: Server, socket: Socket, dat
// Use the simple bulk update function with group_by parameter
const q = `SELECT update_task_sort_orders_bulk($1, $2);`;
await db.query(q, [JSON.stringify(data.task_updates), data.group_by || 'status']);
await db.query(q, [JSON.stringify(data.task_updates), data.group_by || "status"]);
await emitSortOrderChange(data, socket);
// Handle notifications and logging