|
1 | 1 | -- ============================================================================ |
2 | | --- Mina rollback: remove zkapp_states_nullable.element8..element31 + FKs |
3 | | --- Idempotent, online-safe, and updates schema_version.status -> 'rolled_back' |
| 2 | +-- Mina rollback: from mesa to berkeley |
| 3 | +-- + remove zkapp_states_nullable.element31..element8 (int) |
| 4 | +-- + record status in migration_history |
4 | 5 | -- ============================================================================ |
5 | 6 |
|
| 7 | +-- NOTE: When modifying this script, please keep TXNs small, and idempotent |
| 8 | + |
| 9 | +-- Fail fast |
| 10 | +\set ON_ERROR_STOP on |
6 | 11 | -- Keep locks short; abort instead of blocking production traffic. |
7 | 12 | SET lock_timeout = '10s'; |
8 | 13 | SET statement_timeout = '10min'; |
9 | 14 |
|
10 | | --- --- 0) Ensure version table exists & has desired columns -------------------- |
11 | | -CREATE TABLE IF NOT EXISTS public.schema_version ( |
12 | | - version text PRIMARY KEY, |
13 | | - description text, |
14 | | - applied_at timestamptz NOT NULL DEFAULT now() |
15 | | -); |
| 15 | +-- See "src/lib/node_config/version/node_config_version.ml" for protocol version |
| 16 | +SET archive.current_protocol_version = '4.0.0'; |
| 17 | +-- Post-HF protocol version. This one corresponds to Mesa, specifically |
| 18 | +SET archive.target_protocol_version = '3.0.0'; |
| 19 | +-- The version of this script. If you modify the script, please bump the version |
| 20 | +SET archive.migration_version = '0.0.2'; |
16 | 21 |
|
17 | | -DO $$ |
18 | | -BEGIN |
19 | | - IF NOT EXISTS ( |
20 | | - SELECT 1 FROM information_schema.columns |
21 | | - WHERE table_schema='public' AND table_name='schema_version' |
22 | | - AND column_name='status' |
23 | | - ) THEN |
24 | | - ALTER TABLE public.schema_version |
25 | | - ADD COLUMN status text; |
26 | | - END IF; |
| 22 | +-- TODO: put below in a common script |
27 | 23 |
|
28 | | - IF NOT EXISTS ( |
29 | | - SELECT 1 FROM information_schema.columns |
30 | | - WHERE table_schema='public' AND table_name='schema_version' |
31 | | - AND column_name='validated_at' |
32 | | - ) THEN |
33 | | - ALTER TABLE public.schema_version |
34 | | - ADD COLUMN validated_at timestamptz; |
35 | | - END IF; |
36 | | -END$$; |
37 | | - |
38 | | --- Ensure a row for this version exists (so we can mark rolled_back) |
39 | 24 | DO $$ |
40 | | -DECLARE v text := '3.2.0'; |
41 | 25 | BEGIN |
42 | | - IF NOT EXISTS (SELECT 1 FROM public.schema_version WHERE version = v) THEN |
43 | | - INSERT INTO public.schema_version(version, description, status) |
44 | | - VALUES (v, 'Rollback placeholder for elements 8..31 + FKs', 'starting'); |
| 26 | + IF NOT EXISTS (SELECT 1 FROM pg_type WHERE typname = 'migration_status') THEN |
| 27 | + CREATE TYPE migration_status AS ENUM ('starting', 'applied', 'failed'); |
45 | 28 | END IF; |
46 | | -END$$; |
| 29 | +END $$; |
47 | 30 |
|
48 | | --- --- 1) Pre-check: will rollback drop data? --------------------------------- |
49 | | --- By default we abort if any new columns contain data. |
50 | | --- To force a destructive rollback, run in this session first: |
51 | | --- SET mina.allow_destructive_rollback = on; |
52 | | -DO $$ |
| 31 | +CREATE OR REPLACE FUNCTION set_migration_status(p_target_status migration_status) |
| 32 | +RETURNS VOID AS $$ |
53 | 33 | DECLARE |
54 | | - non_null_rows bigint; |
55 | | - allow_rollback boolean := lower(coalesce(current_setting('mina.allow_destructive_rollback', true),'off')) IN ('on','true','1'); |
| 34 | + target_protocol_version text := current_setting('archive.target_protocol_version'); |
| 35 | + target_migration_version text := current_setting('archive.migration_version'); |
56 | 36 | BEGIN |
57 | | - SELECT count(*) INTO non_null_rows |
58 | | - FROM public.zkapp_states_nullable |
59 | | - WHERE |
60 | | - element8 IS NOT NULL OR element9 IS NOT NULL OR element10 IS NOT NULL OR element11 IS NOT NULL OR |
61 | | - element12 IS NOT NULL OR element13 IS NOT NULL OR element14 IS NOT NULL OR element15 IS NOT NULL OR |
62 | | - element16 IS NOT NULL OR element17 IS NOT NULL OR element18 IS NOT NULL OR element19 IS NOT NULL OR |
63 | | - element20 IS NOT NULL OR element21 IS NOT NULL OR element22 IS NOT NULL OR element23 IS NOT NULL OR |
64 | | - element24 IS NOT NULL OR element25 IS NOT NULL OR element26 IS NOT NULL OR element27 IS NOT NULL OR |
65 | | - element28 IS NOT NULL OR element29 IS NOT NULL OR element30 IS NOT NULL OR element31 IS NOT NULL; |
66 | | - |
67 | | - IF non_null_rows > 0 AND NOT allow_rollback THEN |
68 | | - RAISE EXCEPTION |
69 | | - 'Rollback would drop data: % row(s) have non-NULL in element8..element31. Set mina.allow_destructive_rollback=on to force.', |
70 | | - non_null_rows |
71 | | - USING HINT = 'Run: SET mina.allow_destructive_rollback = on; then re-run.'; |
72 | | - ELSE |
73 | | - RAISE NOTICE 'Rollback pre-check: % non-NULL row(s) across element8..element31. Proceeding (forced=%).', |
74 | | - non_null_rows, allow_rollback; |
75 | | - END IF; |
76 | | -END$$; |
| 37 | + UPDATE migration_history mh |
| 38 | + SET status = p_target_status |
| 39 | + FROM ( |
| 40 | + SELECT commit_start_at |
| 41 | + FROM migration_history |
| 42 | + WHERE protocol_version = target_protocol_version |
| 43 | + AND migration_version = target_migration_version |
| 44 | + ORDER BY commit_start_at DESC |
| 45 | + LIMIT 1 |
| 46 | + ) latest |
| 47 | + WHERE mh.commit_start_at = latest.commit_start_at; |
| 48 | +END |
| 49 | +$$ LANGUAGE plpgsql STRICT; |
77 | 50 |
|
78 | | --- --- 2) Drop FKs (reverse order), if present -------------------------------- |
79 | | -DO $$ |
80 | | -DECLARE |
81 | | - fk_record RECORD; |
82 | | - drop_count int := 0; |
83 | | - error_count int := 0; |
84 | | -BEGIN |
85 | | - RAISE NOTICE 'DEBUG: Starting FK removal process...'; |
86 | | - |
87 | | - -- Get all FK constraints for elements 8-31 in reverse order |
88 | | - FOR fk_record IN |
89 | | - SELECT conname |
90 | | - FROM pg_constraint |
91 | | - WHERE conrelid = 'public.zkapp_states_nullable'::regclass |
92 | | - AND contype = 'f' |
93 | | - AND conname LIKE 'zkapp_states_nullable_element%_fk' |
94 | | - AND substring(conname FROM 'element(\d+)_fk')::int BETWEEN 8 AND 31 |
95 | | - ORDER BY conname DESC |
96 | | - LOOP |
97 | | - RAISE NOTICE 'DEBUG: Found FK constraint %, attempting to drop...', fk_record.conname; |
98 | | - BEGIN |
99 | | - EXECUTE format('ALTER TABLE public.zkapp_states_nullable DROP CONSTRAINT %I', fk_record.conname); |
100 | | - RAISE NOTICE 'DEBUG: Successfully dropped constraint %', fk_record.conname; |
101 | | - drop_count := drop_count + 1; |
102 | | - EXCEPTION |
103 | | - WHEN lock_not_available THEN |
104 | | - RAISE NOTICE 'DEBUG: Could not drop %, lock timeout; will remain for now. Re-run later.', fk_record.conname; |
105 | | - error_count := error_count + 1; |
106 | | - WHEN OTHERS THEN |
107 | | - RAISE NOTICE 'DEBUG: Error dropping constraint %: % %', fk_record.conname, SQLSTATE, SQLERRM; |
108 | | - error_count := error_count + 1; |
109 | | - END; |
110 | | - END LOOP; |
111 | | - |
112 | | - RAISE NOTICE 'DEBUG: FK removal process completed. Dropped: %, Errors: %', drop_count, error_count; |
113 | | -END$$; |
| 51 | +-- 1. Ensure version table exists & has desired columns |
| 52 | +CREATE TABLE IF NOT EXISTS migration_history ( |
| 53 | + commit_start_at timestamptz NOT NULL DEFAULT now() PRIMARY KEY, |
| 54 | + protocol_version text NOT NULL, |
| 55 | + migration_version text NOT NULL, |
| 56 | + description text NOT NULL, |
| 57 | + status migration_status NOT NULL |
| 58 | +); |
114 | 59 |
|
115 | | --- --- 3) Drop columns (reverse order), if present ---------------------------- |
| 60 | +-- TODO: put above in a common script |
| 61 | + |
| 62 | +-- Upsert a row for this migration |
116 | 63 | DO $$ |
117 | | -DECLARE |
118 | | - col_record RECORD; |
119 | | - drop_count int := 0; |
120 | | - error_count int := 0; |
| 64 | +DECLARE |
| 65 | + target_protocol_version text := current_setting('archive.target_protocol_version'); |
| 66 | + current_protocol_version text := current_setting('archive.current_protocol_version'); |
| 67 | + target_migration_version text := current_setting('archive.migration_version'); |
| 68 | + latest_protocol_version text; |
| 69 | + latest_migration_version text; |
| 70 | + latest_migration_status migration_status; |
121 | 71 | BEGIN |
122 | | - RAISE NOTICE 'DEBUG: Starting column removal process...'; |
123 | | - |
124 | | - -- Get all columns for elements 8-31 in reverse order |
125 | | - FOR col_record IN |
126 | | - SELECT column_name |
127 | | - FROM information_schema.columns |
128 | | - WHERE table_schema = 'public' |
129 | | - AND table_name = 'zkapp_states_nullable' |
130 | | - AND column_name LIKE 'element%' |
131 | | - AND substring(column_name FROM 'element(\d+)')::int BETWEEN 8 AND 31 |
132 | | - ORDER BY column_name DESC |
133 | | - LOOP |
134 | | - RAISE NOTICE 'DEBUG: Found column %, attempting to drop...', col_record.column_name; |
135 | | - BEGIN |
136 | | - EXECUTE format('ALTER TABLE public.zkapp_states_nullable DROP COLUMN %I', col_record.column_name); |
137 | | - RAISE NOTICE 'DEBUG: Successfully dropped column %', col_record.column_name; |
138 | | - drop_count := drop_count + 1; |
139 | | - EXCEPTION |
140 | | - WHEN lock_not_available THEN |
141 | | - RAISE NOTICE 'DEBUG: Could not drop %, lock timeout; re-run later.', col_record.column_name; |
142 | | - error_count := error_count + 1; |
143 | | - WHEN OTHERS THEN |
144 | | - RAISE NOTICE 'DEBUG: Error dropping column %: % %', col_record.column_name, SQLSTATE, SQLERRM; |
145 | | - error_count := error_count + 1; |
146 | | - END; |
147 | | - END LOOP; |
148 | | - |
149 | | - RAISE NOTICE 'DEBUG: Column removal process completed. Dropped: %, Errors: %', drop_count, error_count; |
| 72 | + -- Try to fetch the existing migration row |
| 73 | + SELECT |
| 74 | + protocol_version, |
| 75 | + migration_version, |
| 76 | + status |
| 77 | + INTO latest_protocol_version, latest_migration_version, latest_migration_status |
| 78 | + FROM migration_history |
| 79 | + ORDER BY commit_start_at DESC |
| 80 | + LIMIT 1; |
| 81 | + |
| 82 | + -- HACK: We don't have a record in migration history in Berkeley, hence |
| 83 | + -- setting to 3.0.0 if it's not present. |
| 84 | + latest_protocol_version := COALESCE(latest_protocol_version, '3.0.0'); |
| 85 | + |
| 86 | + IF latest_protocol_version = current_protocol_version THEN |
| 87 | + INSERT INTO migration_history( |
| 88 | + protocol_version, migration_version, description, status |
| 89 | + ) VALUES ( |
| 90 | + target_protocol_version, |
| 91 | + target_migration_version, |
| 92 | + 'Rollback from Mesa to Berkeley.', |
| 93 | + 'starting'::migration_status |
| 94 | + ); |
| 95 | + ELSIF |
| 96 | + latest_protocol_version = target_protocol_version AND |
| 97 | + latest_migration_version = target_migration_version |
| 98 | + THEN |
| 99 | + RAISE NOTICE |
| 100 | + 'Previous migration in failed/progress/completed, reapplying'; |
| 101 | + ELSE |
| 102 | + RAISE EXCEPTION |
| 103 | + 'Could not apply Migration to current protocol & migration version: (%, %)', |
| 104 | + latest_protocol_version, |
| 105 | + latest_migration_version; |
| 106 | + END IF; |
150 | 107 | END$$; |
151 | 108 |
|
152 | | --- --- 4) Post-check & version table update ----------------------------------- |
153 | | -DO $$ |
| 109 | +CREATE OR REPLACE FUNCTION try_remove_zkapp_states_nullable_element(p_element_num INT) |
| 110 | +RETURNS VOID AS $$ |
154 | 111 | DECLARE |
155 | | - v text := '3.2.0'; |
156 | | - remaining_cols int; |
157 | | - remaining_fks int; |
158 | | - nowtxt text := to_char(now(),'YYYY-MM-DD HH24:MI:SS TZ'); |
159 | | - col_list text := ''; |
160 | | - fk_list text := ''; |
161 | | - rec record; |
| 112 | + col_name TEXT := 'element' || p_element_num; |
162 | 113 | BEGIN |
163 | | - RAISE NOTICE 'DEBUG: Starting post-check analysis...'; |
164 | | - |
165 | | - SELECT count(*) |
166 | | - INTO remaining_cols |
167 | | - FROM generate_series(8,31) g(n) |
168 | | - JOIN information_schema.columns c |
169 | | - ON c.table_schema='public' |
170 | | - AND c.table_name='zkapp_states_nullable' |
171 | | - AND c.column_name='element'||g.n; |
172 | | - |
173 | | - SELECT count(*) |
174 | | - INTO remaining_fks |
175 | | - FROM pg_constraint c |
176 | | - WHERE c.conrelid='public.zkapp_states_nullable'::regclass |
177 | | - AND c.contype='f' |
178 | | - AND c.conname LIKE 'zkapp_states_nullable_element%_fk' |
179 | | - AND substring(c.conname FROM 'element(\d+)_fk')::int BETWEEN 8 AND 31; |
180 | | - |
181 | | - RAISE NOTICE 'DEBUG: Found % remaining columns and % remaining FKs', remaining_cols, remaining_fks; |
182 | | - |
183 | | - -- List remaining columns |
184 | | - IF remaining_cols > 0 THEN |
185 | | - FOR rec IN |
186 | | - SELECT 'element'||g.n as col_name |
187 | | - FROM generate_series(8,31) g(n) |
188 | | - JOIN information_schema.columns c |
189 | | - ON c.table_schema='public' |
190 | | - AND c.table_name='zkapp_states_nullable' |
191 | | - AND c.column_name='element'||g.n |
192 | | - ORDER BY g.n |
193 | | - LOOP |
194 | | - col_list := col_list || rec.col_name || ', '; |
195 | | - END LOOP; |
196 | | - col_list := rtrim(col_list, ', '); |
197 | | - RAISE NOTICE 'DEBUG: Remaining columns: %', col_list; |
198 | | - END IF; |
199 | 114 |
|
200 | | - -- List remaining FKs |
201 | | - IF remaining_fks > 0 THEN |
202 | | - FOR rec IN |
203 | | - SELECT c.conname as fk_name |
204 | | - FROM pg_constraint c |
205 | | - WHERE c.conrelid='public.zkapp_states_nullable'::regclass |
206 | | - AND c.contype='f' |
207 | | - AND c.conname LIKE 'zkapp_states_nullable_element%_fk' |
208 | | - AND substring(c.conname FROM 'element(\d+)_fk')::int BETWEEN 8 AND 31 |
209 | | - ORDER BY c.conname |
210 | | - LOOP |
211 | | - fk_list := fk_list || rec.fk_name || ', '; |
212 | | - END LOOP; |
213 | | - fk_list := rtrim(fk_list, ', '); |
214 | | - RAISE NOTICE 'DEBUG: Remaining FKs: %', fk_list; |
215 | | - END IF; |
| 115 | + RAISE DEBUG 'Trying to removing column % for zkapp_states_nullable', col_name; |
216 | 116 |
|
217 | | - IF remaining_cols = 0 AND remaining_fks = 0 THEN |
218 | | - UPDATE public.schema_version |
219 | | - SET status = 'rolled_back', |
220 | | - description = CASE |
221 | | - WHEN position('ROLLED BACK' in coalesce(description,'')) > 0 |
222 | | - THEN description |
223 | | - ELSE coalesce(description,'') || ' [ROLLED BACK ' || nowtxt || ']' |
224 | | - END, |
225 | | - validated_at = NULL |
226 | | - WHERE version = v; |
227 | | - RAISE NOTICE 'DEBUG: Rollback complete: all target columns and FKs removed. Version marked rolled_back.'; |
228 | | - ELSE |
229 | | - UPDATE public.schema_version |
230 | | - SET status = 'rollback_partial', |
231 | | - description = CASE |
232 | | - WHEN position('ROLLBACK PARTIAL' in coalesce(description,'')) > 0 |
233 | | - THEN description |
234 | | - ELSE coalesce(description,'') || ' [ROLLBACK PARTIAL ' || nowtxt || ']' |
235 | | - END |
236 | | - WHERE version = v; |
237 | | - RAISE NOTICE 'DEBUG: Rollback partial: % column(s) and % FK(s) remain. Re-run to finish.', |
238 | | - remaining_cols, remaining_fks; |
239 | | - END IF; |
240 | | -END$$; |
| 117 | + EXECUTE format( |
| 118 | + 'ALTER TABLE zkapp_states_nullable DROP COLUMN IF EXISTS %I', |
| 119 | + col_name |
| 120 | + ); |
| 121 | + |
| 122 | + RAISE DEBUG 'Ensured column % for zkapp_states_nullable not existent', col_name; |
| 123 | +EXCEPTION |
| 124 | + WHEN OTHERS THEN |
| 125 | + PERFORM set_migration_status('failed'::migration_status); |
| 126 | + RAISE EXCEPTION 'An error occurred: %', SQLERRM; |
| 127 | +END |
| 128 | +$$ LANGUAGE plpgsql; |
| 129 | + |
| 130 | +-- 2. `zkapp_states_nullable`: Remove nullable columns element31..element8 |
| 131 | + |
| 132 | +SELECT try_remove_zkapp_states_nullable_element(31); |
| 133 | +SELECT try_remove_zkapp_states_nullable_element(30); |
| 134 | +SELECT try_remove_zkapp_states_nullable_element(29); |
| 135 | +SELECT try_remove_zkapp_states_nullable_element(28); |
| 136 | +SELECT try_remove_zkapp_states_nullable_element(27); |
| 137 | +SELECT try_remove_zkapp_states_nullable_element(26); |
| 138 | +SELECT try_remove_zkapp_states_nullable_element(25); |
| 139 | +SELECT try_remove_zkapp_states_nullable_element(24); |
| 140 | +SELECT try_remove_zkapp_states_nullable_element(23); |
| 141 | +SELECT try_remove_zkapp_states_nullable_element(22); |
| 142 | +SELECT try_remove_zkapp_states_nullable_element(21); |
| 143 | +SELECT try_remove_zkapp_states_nullable_element(20); |
| 144 | +SELECT try_remove_zkapp_states_nullable_element(19); |
| 145 | +SELECT try_remove_zkapp_states_nullable_element(18); |
| 146 | +SELECT try_remove_zkapp_states_nullable_element(17); |
| 147 | +SELECT try_remove_zkapp_states_nullable_element(16); |
| 148 | +SELECT try_remove_zkapp_states_nullable_element(15); |
| 149 | +SELECT try_remove_zkapp_states_nullable_element(14); |
| 150 | +SELECT try_remove_zkapp_states_nullable_element(13); |
| 151 | +SELECT try_remove_zkapp_states_nullable_element(12); |
| 152 | +SELECT try_remove_zkapp_states_nullable_element(11); |
| 153 | +SELECT try_remove_zkapp_states_nullable_element(10); |
| 154 | +SELECT try_remove_zkapp_states_nullable_element(9); |
| 155 | +SELECT try_remove_zkapp_states_nullable_element(8); |
| 156 | + |
| 157 | +-- 3. Update schema_history |
| 158 | + |
| 159 | +DO $$ |
| 160 | +BEGIN |
| 161 | + PERFORM set_migration_status('applied'::migration_status); |
| 162 | +EXCEPTION |
| 163 | + WHEN OTHERS THEN |
| 164 | + RAISE NOTICE 'An error occurred: %', SQLERRM; |
| 165 | + PERFORM set_migration_status('failed'::migration_status); |
| 166 | +END$$ |
0 commit comments