1+ -- Fix Duplicate Sort Orders Script
2+ -- This script detects and fixes duplicate sort order values that break task ordering
3+
4+ -- 1. DETECTION QUERIES - Run these first to see the scope of the problem
5+
6+ -- Check for duplicates in main sort_order column
7+ SELECT
8+ project_id,
9+ sort_order,
10+ COUNT (* ) as duplicate_count,
11+ STRING_AGG(id::text , ' , ' ) as task_ids
12+ FROM tasks
13+ WHERE project_id IS NOT NULL
14+ GROUP BY project_id, sort_order
15+ HAVING COUNT (* ) > 1
16+ ORDER BY project_id, sort_order;
17+
18+ -- Check for duplicates in status_sort_order
19+ SELECT
20+ project_id,
21+ status_sort_order,
22+ COUNT (* ) as duplicate_count,
23+ STRING_AGG(id::text , ' , ' ) as task_ids
24+ FROM tasks
25+ WHERE project_id IS NOT NULL
26+ GROUP BY project_id, status_sort_order
27+ HAVING COUNT (* ) > 1
28+ ORDER BY project_id, status_sort_order;
29+
30+ -- Check for duplicates in priority_sort_order
31+ SELECT
32+ project_id,
33+ priority_sort_order,
34+ COUNT (* ) as duplicate_count,
35+ STRING_AGG(id::text , ' , ' ) as task_ids
36+ FROM tasks
37+ WHERE project_id IS NOT NULL
38+ GROUP BY project_id, priority_sort_order
39+ HAVING COUNT (* ) > 1
40+ ORDER BY project_id, priority_sort_order;
41+
42+ -- Check for duplicates in phase_sort_order
43+ SELECT
44+ project_id,
45+ phase_sort_order,
46+ COUNT (* ) as duplicate_count,
47+ STRING_AGG(id::text , ' , ' ) as task_ids
48+ FROM tasks
49+ WHERE project_id IS NOT NULL
50+ GROUP BY project_id, phase_sort_order
51+ HAVING COUNT (* ) > 1
52+ ORDER BY project_id, phase_sort_order;
53+
54+ -- Note: member_sort_order removed - no longer used
55+
56+ -- 2. CLEANUP FUNCTIONS
57+
58+ -- Fix duplicates in main sort_order column
59+ CREATE OR REPLACE FUNCTION fix_sort_order_duplicates () RETURNS void
60+ LANGUAGE plpgsql
61+ AS
62+ $$
63+ DECLARE
64+ _project RECORD;
65+ _task RECORD;
66+ _counter INTEGER ;
67+ BEGIN
68+ -- For each project, reassign sort_order values to ensure uniqueness
69+ FOR _project IN
70+ SELECT DISTINCT project_id
71+ FROM tasks
72+ WHERE project_id IS NOT NULL
73+ LOOP
74+ _counter := 0 ;
75+
76+ -- Reassign sort_order values sequentially for this project
77+ FOR _task IN
78+ SELECT id
79+ FROM tasks
80+ WHERE project_id = _project .project_id
81+ ORDER BY sort_order, created_at
82+ LOOP
83+ UPDATE tasks
84+ SET sort_order = _counter
85+ WHERE id = _task .id ;
86+
87+ _counter := _counter + 1 ;
88+ END LOOP;
89+ END LOOP;
90+
91+ RAISE NOTICE ' Fixed sort_order duplicates for all projects' ;
92+ END
93+ $$;
94+
95+ -- Fix duplicates in status_sort_order column
96+ CREATE OR REPLACE FUNCTION fix_status_sort_order_duplicates () RETURNS void
97+ LANGUAGE plpgsql
98+ AS
99+ $$
100+ DECLARE
101+ _project RECORD;
102+ _task RECORD;
103+ _counter INTEGER ;
104+ BEGIN
105+ FOR _project IN
106+ SELECT DISTINCT project_id
107+ FROM tasks
108+ WHERE project_id IS NOT NULL
109+ LOOP
110+ _counter := 0 ;
111+
112+ FOR _task IN
113+ SELECT id
114+ FROM tasks
115+ WHERE project_id = _project .project_id
116+ ORDER BY status_sort_order, created_at
117+ LOOP
118+ UPDATE tasks
119+ SET status_sort_order = _counter
120+ WHERE id = _task .id ;
121+
122+ _counter := _counter + 1 ;
123+ END LOOP;
124+ END LOOP;
125+
126+ RAISE NOTICE ' Fixed status_sort_order duplicates for all projects' ;
127+ END
128+ $$;
129+
130+ -- Fix duplicates in priority_sort_order column
131+ CREATE OR REPLACE FUNCTION fix_priority_sort_order_duplicates () RETURNS void
132+ LANGUAGE plpgsql
133+ AS
134+ $$
135+ DECLARE
136+ _project RECORD;
137+ _task RECORD;
138+ _counter INTEGER ;
139+ BEGIN
140+ FOR _project IN
141+ SELECT DISTINCT project_id
142+ FROM tasks
143+ WHERE project_id IS NOT NULL
144+ LOOP
145+ _counter := 0 ;
146+
147+ FOR _task IN
148+ SELECT id
149+ FROM tasks
150+ WHERE project_id = _project .project_id
151+ ORDER BY priority_sort_order, created_at
152+ LOOP
153+ UPDATE tasks
154+ SET priority_sort_order = _counter
155+ WHERE id = _task .id ;
156+
157+ _counter := _counter + 1 ;
158+ END LOOP;
159+ END LOOP;
160+
161+ RAISE NOTICE ' Fixed priority_sort_order duplicates for all projects' ;
162+ END
163+ $$;
164+
165+ -- Fix duplicates in phase_sort_order column
166+ CREATE OR REPLACE FUNCTION fix_phase_sort_order_duplicates () RETURNS void
167+ LANGUAGE plpgsql
168+ AS
169+ $$
170+ DECLARE
171+ _project RECORD;
172+ _task RECORD;
173+ _counter INTEGER ;
174+ BEGIN
175+ FOR _project IN
176+ SELECT DISTINCT project_id
177+ FROM tasks
178+ WHERE project_id IS NOT NULL
179+ LOOP
180+ _counter := 0 ;
181+
182+ FOR _task IN
183+ SELECT id
184+ FROM tasks
185+ WHERE project_id = _project .project_id
186+ ORDER BY phase_sort_order, created_at
187+ LOOP
188+ UPDATE tasks
189+ SET phase_sort_order = _counter
190+ WHERE id = _task .id ;
191+
192+ _counter := _counter + 1 ;
193+ END LOOP;
194+ END LOOP;
195+
196+ RAISE NOTICE ' Fixed phase_sort_order duplicates for all projects' ;
197+ END
198+ $$;
199+
200+ -- Note: fix_member_sort_order_duplicates() removed - no longer needed
201+
202+ -- Master function to fix all sort order duplicates
203+ CREATE OR REPLACE FUNCTION fix_all_duplicate_sort_orders () RETURNS void
204+ LANGUAGE plpgsql
205+ AS
206+ $$
207+ BEGIN
208+ RAISE NOTICE ' Starting sort order cleanup for all columns...' ;
209+
210+ PERFORM fix_sort_order_duplicates();
211+ PERFORM fix_status_sort_order_duplicates();
212+ PERFORM fix_priority_sort_order_duplicates();
213+ PERFORM fix_phase_sort_order_duplicates();
214+
215+ RAISE NOTICE ' Completed sort order cleanup for all columns' ;
216+ END
217+ $$;
218+
219+ -- 3. VERIFICATION FUNCTION
220+
221+ -- Verify that duplicates have been fixed
222+ CREATE OR REPLACE FUNCTION verify_sort_order_integrity () RETURNS TABLE(
223+ column_name text ,
224+ project_id uuid,
225+ duplicate_count bigint ,
226+ status text
227+ )
228+ LANGUAGE plpgsql
229+ AS
230+ $$
231+ BEGIN
232+ -- Check sort_order duplicates
233+ RETURN QUERY
234+ SELECT
235+ ' sort_order' ::text as column_name,
236+ t .project_id ,
237+ COUNT (* ) as duplicate_count,
238+ CASE WHEN COUNT (* ) > 1 THEN ' DUPLICATES FOUND' ELSE ' OK' END as status
239+ FROM tasks t
240+ WHERE t .project_id IS NOT NULL
241+ GROUP BY t .project_id , t .sort_order
242+ HAVING COUNT (* ) > 1 ;
243+
244+ -- Check status_sort_order duplicates
245+ RETURN QUERY
246+ SELECT
247+ ' status_sort_order' ::text as column_name,
248+ t .project_id ,
249+ COUNT (* ) as duplicate_count,
250+ CASE WHEN COUNT (* ) > 1 THEN ' DUPLICATES FOUND' ELSE ' OK' END as status
251+ FROM tasks t
252+ WHERE t .project_id IS NOT NULL
253+ GROUP BY t .project_id , t .status_sort_order
254+ HAVING COUNT (* ) > 1 ;
255+
256+ -- Check priority_sort_order duplicates
257+ RETURN QUERY
258+ SELECT
259+ ' priority_sort_order' ::text as column_name,
260+ t .project_id ,
261+ COUNT (* ) as duplicate_count,
262+ CASE WHEN COUNT (* ) > 1 THEN ' DUPLICATES FOUND' ELSE ' OK' END as status
263+ FROM tasks t
264+ WHERE t .project_id IS NOT NULL
265+ GROUP BY t .project_id , t .priority_sort_order
266+ HAVING COUNT (* ) > 1 ;
267+
268+ -- Check phase_sort_order duplicates
269+ RETURN QUERY
270+ SELECT
271+ ' phase_sort_order' ::text as column_name,
272+ t .project_id ,
273+ COUNT (* ) as duplicate_count,
274+ CASE WHEN COUNT (* ) > 1 THEN ' DUPLICATES FOUND' ELSE ' OK' END as status
275+ FROM tasks t
276+ WHERE t .project_id IS NOT NULL
277+ GROUP BY t .project_id , t .phase_sort_order
278+ HAVING COUNT (* ) > 1 ;
279+
280+ -- Note: member_sort_order verification removed - column no longer used
281+
282+ END
283+ $$;
284+
285+ -- 4. USAGE INSTRUCTIONS
286+
287+ /*
288+ USAGE:
289+
290+ 1. First, run the detection queries to see which projects have duplicates
291+ 2. Then run this to fix all duplicates:
292+ SELECT fix_all_duplicate_sort_orders();
293+ 3. Finally, verify the fix worked:
294+ SELECT * FROM verify_sort_order_integrity();
295+
296+ If verification returns no rows, all duplicates have been fixed successfully.
297+
298+ WARNING: This will reassign sort order values based on current order + creation time.
299+ Make sure to backup your database before running these functions.
300+ */
0 commit comments