-- 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; $$;