diff --git a/supabase/nightly_sprint_rollover.sql b/supabase/nightly_sprint_rollover.sql new file mode 100644 index 0000000..b1503a7 --- /dev/null +++ b/supabase/nightly_sprint_rollover.sql @@ -0,0 +1,69 @@ +-- Nightly sprint auto-close + rollover job +-- Schedule: 12:01 AM UTC every day + +CREATE EXTENSION IF NOT EXISTS pg_cron; + +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, project_id + FROM public.sprints + WHERE status <> 'completed' + AND end_date < CURRENT_DATE + ORDER BY end_date ASC, start_date ASC + LOOP + -- Pick the next non-completed sprint in the same project. + SELECT s.id + INTO next_sprint_id + FROM public.sprints s + WHERE s.project_id = ended_sprint.project_id + AND 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; +$$; + +DO $$ +DECLARE + existing_job_id BIGINT; +BEGIN + -- Keep this idempotent: replace existing job if present. + SELECT jobid + INTO existing_job_id + FROM cron.job + WHERE jobname = 'nightly-sprint-rollover-0001' + LIMIT 1; + + IF existing_job_id IS NOT NULL THEN + PERFORM cron.unschedule(existing_job_id); + END IF; + + PERFORM cron.schedule( + 'nightly-sprint-rollover-0001', + '1 0 * * *', + 'select public.complete_ended_sprints_and_rollover();' + ); +END; +$$; + diff --git a/supabase/schema.sql b/supabase/schema.sql index f540376..4dbb96b 100644 --- a/supabase/schema.sql +++ b/supabase/schema.sql @@ -241,3 +241,75 @@ BEGIN DELETE FROM password_reset_tokens WHERE expires_at <= NOW() OR used = true; END; $$ LANGUAGE plpgsql; + +-- ============================================ +-- NIGHTLY SPRINT AUTO-CLOSE + ROLLOVER +-- ============================================ +-- Runs every night at 12:01 AM UTC. +-- If you need local time, convert your desired local time to UTC in the cron expression. + +CREATE EXTENSION IF NOT EXISTS pg_cron; + +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, project_id + FROM public.sprints + WHERE status <> 'completed' + AND end_date < CURRENT_DATE + ORDER BY end_date ASC, start_date ASC + LOOP + -- Pick the next non-completed sprint in the same project. + SELECT s.id + INTO next_sprint_id + FROM public.sprints s + WHERE s.project_id = ended_sprint.project_id + AND 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; +$$; + +DO $$ +DECLARE + existing_job_id BIGINT; +BEGIN + -- Keep this idempotent: replace existing job if present. + SELECT jobid + INTO existing_job_id + FROM cron.job + WHERE jobname = 'nightly-sprint-rollover-0001' + LIMIT 1; + + IF existing_job_id IS NOT NULL THEN + PERFORM cron.unschedule(existing_job_id); + END IF; + + PERFORM cron.schedule( + 'nightly-sprint-rollover-0001', + '1 0 * * *', + 'select public.complete_ended_sprints_and_rollover();' + ); +END; +$$;