-
Notifications
You must be signed in to change notification settings - Fork 45.2k
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
feat(backend): Migrate json encoded string columns into a native json…
… column (#9475) ### Changes 🏗️ Due to the legacy of SQLite usage, some of the JSON columns are actually a string column string a stringified JSON column. The scope of this PR is migrating those columns into an actual JSON column. ### Checklist 📋 #### For code changes: - [ ] I have clearly listed my changes in the PR description - [ ] I have made a test plan - [ ] I have tested my changes according to the test plan: <!-- Put your test plan here: --> - [ ] ... <details> <summary>Example test plan</summary> - [ ] Create from scratch and execute an agent with at least 3 blocks - [ ] Import an agent from file upload, and confirm it executes correctly - [ ] Upload agent to marketplace - [ ] Import an agent from marketplace and confirm it executes correctly - [ ] Edit an agent from monitor, and confirm it executes correctly </details> #### For configuration changes: - [ ] `.env.example` is updated or already compatible with my changes - [ ] `docker-compose.yml` is updated or already compatible with my changes - [ ] I have included a list of my configuration changes in the PR description (under **Changes**) <details> <summary>Examples of configuration changes</summary> - Changing ports - Adding new services that need to communicate with each other - Secrets or environment variable changes - New or infrastructure changes such as databases </details>
- Loading branch information
Showing
6 changed files
with
116 additions
and
39 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
77 changes: 77 additions & 0 deletions
77
autogpt_platform/backend/migrations/20250213110232_migrate_string_json/migration.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,77 @@ | ||
CREATE OR REPLACE FUNCTION migrate_text_column_to_json( | ||
p_table text, -- Table name, e.g. 'AgentNodeExecution' | ||
p_col text, -- Column name to convert, e.g. 'executionData' | ||
p_default json DEFAULT '{}'::json, -- Fallback value when original value is NULL. | ||
-- Pass NULL here if you prefer to leave NULLs. | ||
p_set_nullable boolean DEFAULT true -- If false, the new column will be NOT NULL. | ||
) RETURNS void AS $$ | ||
DECLARE | ||
full_table text; | ||
tmp_col text; | ||
BEGIN | ||
-- Build a fully qualified table name using the current schema. | ||
full_table := format('%I.%I', current_schema(), p_table); | ||
tmp_col := p_col || '_tmp'; | ||
|
||
-- 0. Skip the migration if the column is already of type jsonb. | ||
IF EXISTS ( | ||
SELECT 1 | ||
FROM information_schema.columns | ||
WHERE table_schema = current_schema() | ||
AND table_name = p_table | ||
AND column_name = p_col | ||
AND data_type = 'jsonb' | ||
) THEN | ||
RAISE NOTICE 'Column %I.%I is already of type jsonb, skipping migration.', full_table, p_col; | ||
RETURN; | ||
END IF; | ||
|
||
-- 1. Cleanup the original column from invalid JSON characters. | ||
EXECUTE format('UPDATE %s SET %I = replace(%I, E''\\u0000'', '''') WHERE %I LIKE ''%%\\u0000%%'';', full_table, p_col, p_col, p_col); | ||
|
||
-- 2. Add the temporary column of type JSON. | ||
EXECUTE format('ALTER TABLE %s ADD COLUMN %I jsonb;', full_table, tmp_col); | ||
|
||
-- 3. Convert the data: | ||
-- - If p_default IS NOT NULL, use it as the fallback value. | ||
-- - Otherwise, keep NULL. | ||
IF p_default IS NULL THEN | ||
EXECUTE format( | ||
'UPDATE %s SET %I = CASE WHEN %I IS NULL THEN NULL ELSE %I::json END;', | ||
full_table, tmp_col, p_col, p_col | ||
); | ||
ELSE | ||
EXECUTE format( | ||
'UPDATE %s SET %I = CASE WHEN %I IS NULL THEN %L::json ELSE %I::json END;', | ||
full_table, tmp_col, p_col, p_default::text, p_col | ||
); | ||
END IF; | ||
|
||
-- 4. Drop the original text column. | ||
EXECUTE format('ALTER TABLE %s DROP COLUMN %I;', full_table, p_col); | ||
|
||
-- 5. Rename the temporary column to the original column name. | ||
EXECUTE format('ALTER TABLE %s RENAME COLUMN %I TO %I;', full_table, tmp_col, p_col); | ||
|
||
-- 6. Optionally set a DEFAULT for future inserts if a fallback is provided. | ||
IF p_default IS NOT NULL THEN | ||
EXECUTE format('ALTER TABLE %s ALTER COLUMN %I SET DEFAULT %L::json;', | ||
full_table, p_col, p_default::text); | ||
END IF; | ||
|
||
-- 7. Optionally mark the column as NOT NULL. | ||
IF NOT p_set_nullable THEN | ||
EXECUTE format('ALTER TABLE %s ALTER COLUMN %I SET NOT NULL;', full_table, p_col); | ||
END IF; | ||
END; | ||
$$ LANGUAGE plpgsql; | ||
|
||
|
||
BEGIN; | ||
SELECT migrate_text_column_to_json('AgentGraphExecution', 'stats', NULL, true); | ||
SELECT migrate_text_column_to_json('AgentNodeExecution', 'stats', NULL, true); | ||
SELECT migrate_text_column_to_json('AgentNodeExecution', 'executionData', NULL, true); | ||
SELECT migrate_text_column_to_json('AgentNode', 'constantInput', '{}'::json, false); | ||
SELECT migrate_text_column_to_json('AgentNode', 'metadata', '{}'::json, false); | ||
SELECT migrate_text_column_to_json('AgentNodeExecutionInputOutput', 'data', NULL, false); | ||
COMMIT; |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters