gantt-board/supabase/remove_sprint_project_id.sql

50 lines
1.2 KiB
PL/PgSQL

-- Removes sprint -> project coupling.
-- Run once against the existing database before using sprint create/update flows.
BEGIN;
DROP INDEX IF EXISTS idx_sprints_project_id;
ALTER TABLE public.sprints DROP CONSTRAINT IF EXISTS sprints_project_id_fkey;
ALTER TABLE public.sprints DROP COLUMN IF EXISTS project_id;
CREATE OR REPLACE FUNCTION public.complete_ended_sprints_and_rollover()
RETURNS void
LANGUAGE plpgsql
SECURITY DEFINER
SET search_path = public
AS $$
DECLARE
ended_sprint RECORD;
next_sprint_id UUID;
BEGIN
FOR ended_sprint IN
SELECT id
FROM public.sprints
WHERE status <> 'completed'
AND end_date < CURRENT_DATE
ORDER BY end_date ASC, start_date ASC
LOOP
SELECT s.id
INTO next_sprint_id
FROM public.sprints s
WHERE s.status <> 'completed'
AND s.id <> ended_sprint.id
ORDER BY s.start_date ASC
LIMIT 1;
IF next_sprint_id IS NOT NULL THEN
UPDATE public.tasks
SET sprint_id = next_sprint_id
WHERE sprint_id = ended_sprint.id
AND status NOT IN ('done', 'canceled', 'archived');
END IF;
UPDATE public.sprints
SET status = 'completed'
WHERE id = ended_sprint.id;
END LOOP;
END;
$$;
COMMIT;