Skip to content

Commit 1d05039

Browse files
committed
# Fix: Add automatic data migration for map step type migration
(#234) ## Summary Updates migration `20251006073122_pgflow_add_map_step_type.sql` to automatically handle existing production data when transitioning from single-task-only schema to map step schema. ## Changes ### Migration Updates - Split schema changes into 3 steps to avoid constraint violations: 1. Drop old constraints and NOT NULL requirement 2. Run automatic data backfill (UPDATE statements) 3. Add new constraints ### Automatic Data Migration The migration now automatically: - Backfills `initial_tasks = 1` for all existing steps (correct for pre-map-step schema where all steps had exactly 1 task) - Sets `remaining_tasks = NULL` for 'created' status steps (new semantics: NULL = not started) ### Pre-Migration Verification Added `pkgs/core/queries/PRE_MIGRATION_CHECK_20251006073122.sql`: - Read-only query to verify migration will succeed - Shows exactly which runs/steps will be auto-fixed - Provides copy/paste-friendly output for Discord support - Only needed for production databases with existing data ### Documentation Updated `.changeset/add-map-step-type-infrastructure.md`: - Added WARNING callout about automatic data migration - Added TIP callout with verification instructions - Includes expected output example - Clarifies this is for production databases only (not local dev) ## Testing Migration tested against production-like data with existing `created` and `started` steps. All constraint violations are automatically resolved. ## User Impact **No manual intervention required.** Migration handles all data cleanup automatically. Users can optionally verify beforehand using the pre-migration check query.
1 parent 7127012 commit 1d05039

File tree

8 files changed

+135
-184
lines changed

8 files changed

+135
-184
lines changed

.changeset/add-map-step-type-infrastructure.md

Lines changed: 32 additions & 15 deletions
Original file line numberDiff line numberDiff line change
@@ -4,24 +4,41 @@
44

55
Add map step type infrastructure in SQL core
66

7-
## 🚨🚨🚨 CRITICAL MIGRATION WARNING 🚨🚨🚨
7+
> [!WARNING]
8+
> **This migration includes automatic data migration**
9+
>
10+
> The migration will automatically update existing `step_states` rows to satisfy new constraints. This should complete without issues due to strict check constraints enforced in previous versions.
811
9-
**THIS MIGRATION REQUIRES MANUAL DATA UPDATE BEFORE DEPLOYMENT!**
12+
> [!TIP]
13+
> **Optional: Verify before deploying to production**
14+
>
15+
> If you have existing production data and want to verify the migration will succeed cleanly, run this **read-only check query** (does not modify data) in **Supabase Studio** against your **production database**:
16+
>
17+
> 1. Open Supabase Studio → SQL Editor
18+
> 2. Copy contents of `pkgs/core/queries/PRE_MIGRATION_CHECK_20251006073122.sql`
19+
> 3. Execute against your production database (not local dev!)
20+
> 4. Review results
21+
>
22+
> **Expected output for successful migration:**
23+
> ```
24+
> type | identifier | details
25+
> ----------------------|---------------------------|---------------------------
26+
> ISSUE_1_AUTO_FIXED | run=abc12345 step=load | status=created remaining_tasks=1 → will set to NULL
27+
> ISSUE_2_AUTO_FIXED | run=def67890 step=process | status=started → will set initial_tasks=1
28+
> INFO_SUMMARY | total_step_states=42 | created=5 started=2 completed=30 failed=5
29+
> ```
30+
>
31+
> **Interpretation:**
32+
> - ✅ Only `ISSUE_1_AUTO_FIXED`, `ISSUE_2_AUTO_FIXED`, and `INFO_SUMMARY` rows? **Safe to migrate**
33+
> - 🆘 Unexpected issues or errors? Copy output and share on Discord for help
34+
>
35+
> **Note:** This check only returns results indicating correctness or problems - it does not modify any data. Only useful for production databases with existing runs.
1036
11-
The migration adds a new constraint `remaining_tasks_state_consistency` that will **FAIL ON EXISTING DATA** if not handled properly.
37+
**Automatic data updates:**
38+
- Sets `initial_tasks = 1` for all existing steps (correct for pre-map-step schema)
39+
- Sets `remaining_tasks = NULL` for 'created' status steps (new semantics)
1240
13-
### Required Data Migration:
14-
15-
Before applying this migration to any environment with existing data, you MUST include:
16-
17-
```sql
18-
-- CRITICAL: Update existing step_states to satisfy new constraint
19-
UPDATE pgflow.step_states
20-
SET remaining_tasks = NULL
21-
WHERE status = 'created';
22-
```
23-
24-
**Without this update, the migration WILL FAIL in production!** The new constraint requires that `remaining_tasks` can only be set when `status != 'created'`.
41+
No manual intervention required.
2542
2643
---
2744
Lines changed: 77 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,77 @@
1+
-- ================================================================================
2+
-- PRE-MIGRATION CHECK for 20251006073122_pgflow_add_map_step_type.sql
3+
-- ================================================================================
4+
-- Purpose: Verify the migration will succeed cleanly on your database
5+
-- When to run: BEFORE applying the migration
6+
-- What to do with output:
7+
-- - ✅ Only INFO rows? You're good to migrate
8+
-- - ⚠️ ISSUE_1/ISSUE_2? Safe - migration auto-fixes these
9+
-- - 🆘 Unexpected issues? Copy/paste output to Discord for help
10+
-- ================================================================================
11+
12+
WITH issues AS (
13+
-- Issue 1: Created steps with remaining_tasks (will be set to NULL)
14+
SELECT
15+
1 AS priority,
16+
'ISSUE_1_AUTO_FIXED' AS type,
17+
format('run=%s step=%s',
18+
LEFT(run_id::text, 8),
19+
step_slug
20+
) AS identifier,
21+
format('status=%s remaining_tasks=%s → will set to NULL',
22+
status,
23+
remaining_tasks
24+
) AS details
25+
FROM pgflow.step_states
26+
WHERE status = 'created' AND remaining_tasks IS NOT NULL
27+
28+
UNION ALL
29+
30+
-- Issue 2: Started steps (will backfill initial_tasks)
31+
SELECT
32+
2 AS priority,
33+
'ISSUE_2_AUTO_FIXED' AS type,
34+
format('run=%s step=%s',
35+
LEFT(run_id::text, 8),
36+
step_slug
37+
) AS identifier,
38+
format('status=%s → will set initial_tasks=%s',
39+
status,
40+
COALESCE(remaining_tasks::text, '1')
41+
) AS details
42+
FROM pgflow.step_states
43+
WHERE status = 'started'
44+
45+
UNION ALL
46+
47+
-- Info: Summary stats
48+
SELECT
49+
999 AS priority,
50+
'INFO_SUMMARY' AS type,
51+
format('total_step_states=%s', COUNT(*)) AS identifier,
52+
format('created=%s started=%s completed=%s failed=%s',
53+
COUNT(*) FILTER (WHERE status = 'created'),
54+
COUNT(*) FILTER (WHERE status = 'started'),
55+
COUNT(*) FILTER (WHERE status = 'completed'),
56+
COUNT(*) FILTER (WHERE status = 'failed')
57+
) AS details
58+
FROM pgflow.step_states
59+
)
60+
SELECT
61+
type,
62+
identifier,
63+
details
64+
FROM issues
65+
ORDER BY priority, identifier;
66+
67+
-- ================================================================================
68+
-- HOW TO READ THE OUTPUT:
69+
-- ================================================================================
70+
-- type | identifier | details
71+
-- ----------------------|-------------------------|---------------------------
72+
-- ISSUE_1_AUTO_FIXED | run=abc12345 step=foo | Will be cleaned up
73+
-- ISSUE_2_AUTO_FIXED | run=def67890 step=bar | Will be backfilled
74+
-- INFO_SUMMARY | total_step_states=42 | Overall stats
75+
--
76+
-- ✅ Safe to migrate if you only see ISSUE_1/ISSUE_2 + INFO_SUMMARY
77+
-- ================================================================================

pkgs/core/queries/fail_permanently.sql

Lines changed: 0 additions & 17 deletions
This file was deleted.

pkgs/core/queries/fail_task.sql

Lines changed: 0 additions & 21 deletions
This file was deleted.

pkgs/core/queries/sequential.sql

Lines changed: 0 additions & 59 deletions
This file was deleted.

pkgs/core/queries/two_roots_left_right.sql

Lines changed: 0 additions & 63 deletions
This file was deleted.

pkgs/core/supabase/migrations/20251006073122_pgflow_add_map_step_type.sql

Lines changed: 24 additions & 7 deletions
Original file line numberDiff line numberDiff line change
@@ -1,14 +1,31 @@
11
-- Modify "step_task_record" composite type
22
ALTER TYPE "pgflow"."step_task_record" ADD ATTRIBUTE "task_index" integer;
3-
-- MANUAL DATA MIGRATION: Prepare existing data for new constraint
4-
-- This UPDATE must run BEFORE the new constraint is added to avoid failures
5-
-- The new constraint "remaining_tasks_state_consistency" requires that
6-
-- remaining_tasks is NULL when status = 'created'
3+
-- Modify "step_states" table - Step 1: Drop old constraint and NOT NULL
4+
ALTER TABLE "pgflow"."step_states"
5+
DROP CONSTRAINT "step_states_remaining_tasks_check",
6+
ALTER COLUMN "remaining_tasks" DROP NOT NULL,
7+
ALTER COLUMN "remaining_tasks" DROP DEFAULT,
8+
ADD COLUMN "initial_tasks" integer NULL;
9+
-- AUTOMATIC DATA MIGRATION: Prepare existing data for new constraints
10+
-- This runs AFTER dropping NOT NULL but BEFORE adding new constraints
11+
-- All old steps had exactly 1 task (enforced by old only_single_task_per_step constraint)
12+
13+
-- Backfill initial_tasks = 1 for all existing steps
14+
-- (Old schema enforced exactly 1 task per step, so all steps had initial_tasks=1)
15+
UPDATE "pgflow"."step_states"
16+
SET "initial_tasks" = 1
17+
WHERE "initial_tasks" IS NULL;
18+
19+
-- Set remaining_tasks to NULL for 'created' status
20+
-- (New semantics: NULL = not started, old semantics: 1 = not started)
721
UPDATE "pgflow"."step_states"
822
SET "remaining_tasks" = NULL
9-
WHERE "status" = 'created';
10-
-- Modify "step_states" table
11-
ALTER TABLE "pgflow"."step_states" DROP CONSTRAINT "step_states_remaining_tasks_check", ADD CONSTRAINT "initial_tasks_known_when_started" CHECK ((status <> 'started'::text) OR (initial_tasks IS NOT NULL)), ADD CONSTRAINT "remaining_tasks_state_consistency" CHECK ((remaining_tasks IS NULL) OR (status <> 'created'::text)), ADD CONSTRAINT "step_states_initial_tasks_check" CHECK ((initial_tasks IS NULL) OR (initial_tasks >= 0)), ALTER COLUMN "remaining_tasks" DROP NOT NULL, ALTER COLUMN "remaining_tasks" DROP DEFAULT, ADD COLUMN "initial_tasks" integer NULL;
23+
WHERE "status" = 'created' AND "remaining_tasks" IS NOT NULL;
24+
-- Modify "step_states" table - Step 2: Add new constraints
25+
ALTER TABLE "pgflow"."step_states"
26+
ADD CONSTRAINT "initial_tasks_known_when_started" CHECK ((status <> 'started'::text) OR (initial_tasks IS NOT NULL)),
27+
ADD CONSTRAINT "remaining_tasks_state_consistency" CHECK ((remaining_tasks IS NULL) OR (status <> 'created'::text)),
28+
ADD CONSTRAINT "step_states_initial_tasks_check" CHECK ((initial_tasks IS NULL) OR (initial_tasks >= 0));
1229
-- Modify "step_tasks" table
1330
ALTER TABLE "pgflow"."step_tasks" DROP CONSTRAINT "only_single_task_per_step", DROP CONSTRAINT "output_valid_only_for_completed", ADD CONSTRAINT "output_valid_only_for_completed" CHECK ((output IS NULL) OR (status = ANY (ARRAY['completed'::text, 'failed'::text])));
1431
-- Modify "steps" table
Lines changed: 2 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -1,4 +1,4 @@
1-
h1:A6hL4r68jggxXAl+YKBn+dGczQ3JWLsXvIh1QqnF4hU=
1+
h1:eDZ+F7VXqXxJeuJJTxxV6UTGnFGgvM/++AJVQc+Ao4Y=
22
20250429164909_pgflow_initial.sql h1:5K7OqB/vj73TWJTQquUzn+i6H2wWduaW+Ir1an3QYmQ=
33
20250517072017_pgflow_fix_poll_for_tasks_to_use_separate_statement_for_polling.sql h1:gnT6hYn43p5oIfr0HqoGlqX/4Si+uxMsCBtBa0/Z2Cg=
44
20250609105135_pgflow_add_start_tasks_and_started_status.sql h1:9Yv/elMz9Nht9rCJOybx62eNrUyghsEMbMKeOJPUMVc=
@@ -8,4 +8,4 @@ h1:A6hL4r68jggxXAl+YKBn+dGczQ3JWLsXvIh1QqnF4hU=
88
20250627090700_pgflow_fix_function_search_paths.sql h1:NRMbmDKkOww7pOx1TVERMP5UdjmgfH0wE9QhzfBU3co=
99
20250707210212_pgflow_add_opt_start_delay.sql h1:11J7SDgS6EVFUwxSi0bRZnNQgVGTV0EJGj9yuC0vczY=
1010
20250719205006_pgflow_worker_deprecation.sql h1:L3LDsVrUeABlRBXhHsu60bilfgDKEJHci5xWknH9XIg=
11-
20251006073122_pgflow_add_map_step_type.sql h1:TOAhJ9WcG4mb67nBX+7DRl5UchezNM4CgTilS0wjM94=
11+
20251006073122_pgflow_add_map_step_type.sql h1:CPYy9lf7qUlZrkLzDI/0nH3CSUZZqFwXC6pO84E7Ezg=

0 commit comments

Comments
 (0)