fix(db-postgres): v2-v3 migration errors with relation already exists (#12310)
This fixes issues identified in the predefined migration for
postgres v2-v3 including the following:
### relation already exists
Can error with the following:
```ts
{
err: [DatabaseError],
msg: 'Error running migration 20250502_020052_relationships_v2_v3 column "relation_id" of relation "table_name" already exists.'
}
```
This was happening when you run a migration with both a required
relationship or upload field and no schema specified in the db adapter.
When both of these are true the function that replaces `ADD COLUMN` and
`ALTER COLUMN` in order to add `NOT NULL` constraints for requried
fields, wasn't working. This resulted in the `ADD COLUMN` statement from
being being called multiple times instead of altering it after data had
been copied over.
### camelCase column change
Enum columns from using `select` or `radio` have changed from camelCase
to snake case in v3. This change was not accounted for in the
relationship migration and needed to be accounted for.
### DROP CONSTRAINT
It was pointed out by
[here](https://github.com/payloadcms/payload/issues/10162#issuecomment-2610018940)
that the `DROP CONSTRAINT` needs to include `IF EXISTS` so that it can
continue if the contraint was already removed in a previous statement.
fixes https://github.com/payloadcms/payload/issues/10162
This commit is contained in:
@@ -1,49 +1,126 @@
|
||||
export type Groups =
|
||||
| 'addColumn'
|
||||
| 'addConstraint'
|
||||
| 'alterType'
|
||||
| 'createIndex'
|
||||
| 'createTable'
|
||||
| 'createType'
|
||||
| 'disableRowSecurity'
|
||||
| 'dropColumn'
|
||||
| 'dropConstraint'
|
||||
| 'dropIndex'
|
||||
| 'dropTable'
|
||||
| 'dropType'
|
||||
| 'notNull'
|
||||
| 'renameColumn'
|
||||
| 'setDefault'
|
||||
|
||||
/**
|
||||
* Convert an "ADD COLUMN" statement to an "ALTER COLUMN" statement
|
||||
* example: ALTER TABLE "pages_blocks_my_block" ADD COLUMN "person_id" integer NOT NULL;
|
||||
* to: ALTER TABLE "pages_blocks_my_block" ALTER COLUMN "person_id" SET NOT NULL;
|
||||
* @param sql
|
||||
* Convert an "ADD COLUMN" statement to an "ALTER COLUMN" statement.
|
||||
* Works with or without a schema name.
|
||||
*
|
||||
* Examples:
|
||||
* 'ALTER TABLE "pages_blocks_my_block" ADD COLUMN "person_id" integer NOT NULL;'
|
||||
* => 'ALTER TABLE "pages_blocks_my_block" ALTER COLUMN "person_id" SET NOT NULL;'
|
||||
*
|
||||
* 'ALTER TABLE "public"."pages_blocks_my_block" ADD COLUMN "person_id" integer NOT NULL;'
|
||||
* => 'ALTER TABLE "public"."pages_blocks_my_block" ALTER COLUMN "person_id" SET NOT NULL;'
|
||||
*/
|
||||
function convertAddColumnToAlterColumn(sql) {
|
||||
// Regular expression to match the ADD COLUMN statement with its constraints
|
||||
const regex = /ALTER TABLE ("[^"]+")\.(".*?") ADD COLUMN ("[^"]+") [\w\s]+ NOT NULL;/
|
||||
const regex = /ALTER TABLE ((?:"[^"]+"\.)?"[^"]+") ADD COLUMN ("[^"]+") [^;]*?NOT NULL;/i
|
||||
|
||||
// Replace the matched part with "ALTER COLUMN ... SET NOT NULL;"
|
||||
return sql.replace(regex, 'ALTER TABLE $1.$2 ALTER COLUMN $3 SET NOT NULL;')
|
||||
return sql.replace(regex, 'ALTER TABLE $1 ALTER COLUMN $2 SET NOT NULL;')
|
||||
}
|
||||
|
||||
export const groupUpSQLStatements = (list: string[]): Record<Groups, string[]> => {
|
||||
const groups = {
|
||||
/**
|
||||
* example: ALTER TABLE "posts" ADD COLUMN "category_id" integer
|
||||
*/
|
||||
addColumn: 'ADD COLUMN',
|
||||
// example: ALTER TABLE "posts" ADD COLUMN "category_id" integer
|
||||
|
||||
/**
|
||||
* example:
|
||||
* DO $$ BEGIN
|
||||
* ALTER TABLE "pages_blocks_my_block" ADD CONSTRAINT "pages_blocks_my_block_person_id_users_id_fk" FOREIGN KEY ("person_id") REFERENCES "users"("id") ON DELETE cascade ON UPDATE no action;
|
||||
* EXCEPTION
|
||||
* WHEN duplicate_object THEN null;
|
||||
* END $$;
|
||||
*/
|
||||
addConstraint: 'ADD CONSTRAINT',
|
||||
//example:
|
||||
// DO $$ BEGIN
|
||||
// ALTER TABLE "pages_blocks_my_block" ADD CONSTRAINT "pages_blocks_my_block_person_id_users_id_fk" FOREIGN KEY ("person_id") REFERENCES "users"("id") ON DELETE cascade ON UPDATE no action;
|
||||
// EXCEPTION
|
||||
// WHEN duplicate_object THEN null;
|
||||
// END $$;
|
||||
|
||||
/**
|
||||
* example: CREATE TABLE IF NOT EXISTS "payload_locked_documents" (
|
||||
* "id" serial PRIMARY KEY NOT NULL,
|
||||
* "global_slug" varchar,
|
||||
* "updated_at" timestamp(3) with time zone DEFAULT now() NOT NULL,
|
||||
* "created_at" timestamp(3) with time zone DEFAULT now() NOT NULL
|
||||
* );
|
||||
*/
|
||||
createTable: 'CREATE TABLE',
|
||||
|
||||
/**
|
||||
* example: ALTER TABLE "_posts_v_rels" DROP COLUMN IF EXISTS "posts_id";
|
||||
*/
|
||||
dropColumn: 'DROP COLUMN',
|
||||
// example: ALTER TABLE "_posts_v_rels" DROP COLUMN IF EXISTS "posts_id";
|
||||
|
||||
/**
|
||||
* example: ALTER TABLE "_posts_v_rels" DROP CONSTRAINT "_posts_v_rels_posts_fk";
|
||||
*/
|
||||
dropConstraint: 'DROP CONSTRAINT',
|
||||
// example: ALTER TABLE "_posts_v_rels" DROP CONSTRAINT "_posts_v_rels_posts_fk";
|
||||
|
||||
/**
|
||||
* example: DROP TABLE "pages_rels";
|
||||
*/
|
||||
dropTable: 'DROP TABLE',
|
||||
// example: DROP TABLE "pages_rels";
|
||||
|
||||
/**
|
||||
* example: ALTER TABLE "pages_blocks_my_block" ALTER COLUMN "person_id" SET NOT NULL;
|
||||
*/
|
||||
notNull: 'NOT NULL',
|
||||
// example: ALTER TABLE "pages_blocks_my_block" ALTER COLUMN "person_id" SET NOT NULL;
|
||||
|
||||
/**
|
||||
* example: CREATE TYPE "public"."enum__pages_v_published_locale" AS ENUM('en', 'es');
|
||||
*/
|
||||
createType: 'CREATE TYPE',
|
||||
|
||||
/**
|
||||
* example: ALTER TYPE "public"."enum_pages_blocks_cta" ADD VALUE 'copy';
|
||||
*/
|
||||
alterType: 'ALTER TYPE',
|
||||
|
||||
/**
|
||||
* example: ALTER TABLE "categories_rels" DISABLE ROW LEVEL SECURITY;
|
||||
*/
|
||||
disableRowSecurity: 'DISABLE ROW LEVEL SECURITY;',
|
||||
|
||||
/**
|
||||
* example: DROP INDEX IF EXISTS "pages_title_idx";
|
||||
*/
|
||||
dropIndex: 'DROP INDEX IF EXISTS',
|
||||
|
||||
/**
|
||||
* example: ALTER TABLE "pages" ALTER COLUMN "_status" SET DEFAULT 'draft';
|
||||
*/
|
||||
setDefault: 'SET DEFAULT',
|
||||
|
||||
/**
|
||||
* example: CREATE INDEX IF NOT EXISTS "payload_locked_documents_global_slug_idx" ON "payload_locked_documents" USING btree ("global_slug");
|
||||
*/
|
||||
createIndex: 'INDEX IF NOT EXISTS',
|
||||
|
||||
/**
|
||||
* example: DROP TYPE "public"."enum__pages_v_published_locale";
|
||||
*/
|
||||
dropType: 'DROP TYPE',
|
||||
|
||||
/**
|
||||
* columns were renamed from camelCase to snake_case
|
||||
* example: ALTER TABLE "forms" RENAME COLUMN "confirmationType" TO "confirmation_type";
|
||||
*/
|
||||
renameColumn: 'RENAME COLUMN',
|
||||
}
|
||||
|
||||
const result = Object.keys(groups).reduce((result, group: Groups) => {
|
||||
@@ -51,7 +128,17 @@ export const groupUpSQLStatements = (list: string[]): Record<Groups, string[]> =
|
||||
return result
|
||||
}, {}) as Record<Groups, string[]>
|
||||
|
||||
// push multi-line changes to a single grouping
|
||||
let isCreateTable = false
|
||||
|
||||
for (const line of list) {
|
||||
if (isCreateTable) {
|
||||
result.createTable.push(line)
|
||||
if (line.includes(');')) {
|
||||
isCreateTable = false
|
||||
}
|
||||
continue
|
||||
}
|
||||
Object.entries(groups).some(([key, value]) => {
|
||||
if (line.endsWith('NOT NULL;')) {
|
||||
// split up the ADD COLUMN and ALTER COLUMN NOT NULL statements
|
||||
@@ -64,7 +151,11 @@ export const groupUpSQLStatements = (list: string[]): Record<Groups, string[]> =
|
||||
return true
|
||||
}
|
||||
if (line.includes(value)) {
|
||||
result[key].push(line)
|
||||
let statement = line
|
||||
if (key === 'dropConstraint') {
|
||||
statement = line.replace('" DROP CONSTRAINT "', '" DROP CONSTRAINT IF EXISTS "')
|
||||
}
|
||||
result[key].push(statement)
|
||||
return true
|
||||
}
|
||||
})
|
||||
|
||||
@@ -20,6 +20,17 @@ type Args = {
|
||||
req?: Partial<PayloadRequest>
|
||||
}
|
||||
|
||||
const runStatementGroup = async ({ adapter, db, debug, statements }) => {
|
||||
const addColumnsStatement = statements.join('\n')
|
||||
|
||||
if (debug) {
|
||||
adapter.payload.logger.info(debug)
|
||||
adapter.payload.logger.info(addColumnsStatement)
|
||||
}
|
||||
|
||||
await db.execute(sql.raw(addColumnsStatement))
|
||||
}
|
||||
|
||||
/**
|
||||
* Moves upload and relationship columns from the join table and into the tables while moving data
|
||||
* This is done in the following order:
|
||||
@@ -40,16 +51,7 @@ export const migratePostgresV2toV3 = async ({ debug, payload, req }: Args) => {
|
||||
|
||||
// get the drizzle migrateUpSQL from drizzle using the last schema
|
||||
const { generateDrizzleJson, generateMigration, upSnapshot } = adapter.requireDrizzleKit()
|
||||
|
||||
const toSnapshot: Record<string, unknown> = {}
|
||||
|
||||
for (const key of Object.keys(adapter.schema).filter(
|
||||
(key) => !key.startsWith('payload_locked_documents'),
|
||||
)) {
|
||||
toSnapshot[key] = adapter.schema[key]
|
||||
}
|
||||
|
||||
const drizzleJsonAfter = generateDrizzleJson(toSnapshot) as DrizzleSnapshotJSON
|
||||
const drizzleJsonAfter = generateDrizzleJson(adapter.schema) as DrizzleSnapshotJSON
|
||||
|
||||
// Get the previous migration snapshot
|
||||
const previousSnapshot = fs
|
||||
@@ -81,18 +83,62 @@ export const migratePostgresV2toV3 = async ({ debug, payload, req }: Args) => {
|
||||
|
||||
const sqlUpStatements = groupUpSQLStatements(generatedSQL)
|
||||
|
||||
const addColumnsStatement = sqlUpStatements.addColumn.join('\n')
|
||||
|
||||
if (debug) {
|
||||
payload.logger.info('CREATING NEW RELATIONSHIP COLUMNS')
|
||||
payload.logger.info(addColumnsStatement)
|
||||
}
|
||||
|
||||
const db = await getTransaction(adapter, req)
|
||||
|
||||
await db.execute(sql.raw(addColumnsStatement))
|
||||
await runStatementGroup({
|
||||
adapter,
|
||||
db,
|
||||
debug: debug ? 'CREATING TYPES' : null,
|
||||
statements: sqlUpStatements.createType,
|
||||
})
|
||||
|
||||
await runStatementGroup({
|
||||
adapter,
|
||||
db,
|
||||
debug: debug ? 'ALTERING TYPES' : null,
|
||||
statements: sqlUpStatements.alterType,
|
||||
})
|
||||
|
||||
await runStatementGroup({
|
||||
adapter,
|
||||
db,
|
||||
debug: debug ? 'CREATING TABLES' : null,
|
||||
statements: sqlUpStatements.createTable,
|
||||
})
|
||||
|
||||
await runStatementGroup({
|
||||
adapter,
|
||||
db,
|
||||
debug: debug ? 'RENAMING COLUMNS' : null,
|
||||
statements: sqlUpStatements.renameColumn,
|
||||
})
|
||||
|
||||
await runStatementGroup({
|
||||
adapter,
|
||||
db,
|
||||
debug: debug ? 'CREATING NEW RELATIONSHIP COLUMNS' : null,
|
||||
statements: sqlUpStatements.addColumn,
|
||||
})
|
||||
|
||||
// SET DEFAULTS
|
||||
await runStatementGroup({
|
||||
adapter,
|
||||
db,
|
||||
debug: debug ? 'SETTING DEFAULTS' : null,
|
||||
statements: sqlUpStatements.setDefault,
|
||||
})
|
||||
|
||||
await runStatementGroup({
|
||||
adapter,
|
||||
db,
|
||||
debug: debug ? 'CREATING INDEXES' : null,
|
||||
statements: sqlUpStatements.createIndex,
|
||||
})
|
||||
|
||||
for (const collection of payload.config.collections) {
|
||||
if (collection.slug === 'payload-locked-documents') {
|
||||
continue
|
||||
}
|
||||
const tableName = adapter.tableNameMap.get(toSnakeCase(collection.slug))
|
||||
const pathsToQuery: PathsToQuery = new Set()
|
||||
|
||||
@@ -238,52 +284,58 @@ export const migratePostgresV2toV3 = async ({ debug, payload, req }: Args) => {
|
||||
}
|
||||
|
||||
// ADD CONSTRAINT
|
||||
const addConstraintsStatement = sqlUpStatements.addConstraint.join('\n')
|
||||
|
||||
if (debug) {
|
||||
payload.logger.info('ADDING CONSTRAINTS')
|
||||
payload.logger.info(addConstraintsStatement)
|
||||
}
|
||||
|
||||
await db.execute(sql.raw(addConstraintsStatement))
|
||||
await runStatementGroup({
|
||||
adapter,
|
||||
db,
|
||||
debug: debug ? 'ADDING CONSTRAINTS' : null,
|
||||
statements: sqlUpStatements.addConstraint,
|
||||
})
|
||||
|
||||
// NOT NULL
|
||||
const notNullStatements = sqlUpStatements.notNull.join('\n')
|
||||
|
||||
if (debug) {
|
||||
payload.logger.info('NOT NULL CONSTRAINTS')
|
||||
payload.logger.info(notNullStatements)
|
||||
}
|
||||
|
||||
await db.execute(sql.raw(notNullStatements))
|
||||
await runStatementGroup({
|
||||
adapter,
|
||||
db,
|
||||
debug: debug ? 'NOT NULL CONSTRAINTS' : null,
|
||||
statements: sqlUpStatements.notNull,
|
||||
})
|
||||
|
||||
// DROP TABLE
|
||||
const dropTablesStatement = sqlUpStatements.dropTable.join('\n')
|
||||
await runStatementGroup({
|
||||
adapter,
|
||||
db,
|
||||
debug: debug ? 'DROPPING TABLES' : null,
|
||||
statements: sqlUpStatements.dropTable,
|
||||
})
|
||||
|
||||
if (debug) {
|
||||
payload.logger.info('DROPPING TABLES')
|
||||
payload.logger.info(dropTablesStatement)
|
||||
}
|
||||
|
||||
await db.execute(sql.raw(dropTablesStatement))
|
||||
// DROP INDEX
|
||||
await runStatementGroup({
|
||||
adapter,
|
||||
db,
|
||||
debug: debug ? 'DROPPING INDEXES' : null,
|
||||
statements: sqlUpStatements.dropIndex,
|
||||
})
|
||||
|
||||
// DROP CONSTRAINT
|
||||
const dropConstraintsStatement = sqlUpStatements.dropConstraint.join('\n')
|
||||
|
||||
if (debug) {
|
||||
payload.logger.info('DROPPING CONSTRAINTS')
|
||||
payload.logger.info(dropConstraintsStatement)
|
||||
}
|
||||
|
||||
await db.execute(sql.raw(dropConstraintsStatement))
|
||||
await runStatementGroup({
|
||||
adapter,
|
||||
db,
|
||||
debug: debug ? 'DROPPING CONSTRAINTS' : null,
|
||||
statements: sqlUpStatements.dropConstraint,
|
||||
})
|
||||
|
||||
// DROP COLUMN
|
||||
const dropColumnsStatement = sqlUpStatements.dropColumn.join('\n')
|
||||
await runStatementGroup({
|
||||
adapter,
|
||||
db,
|
||||
debug: debug ? 'DROPPING COLUMNS' : null,
|
||||
statements: sqlUpStatements.dropColumn,
|
||||
})
|
||||
|
||||
if (debug) {
|
||||
payload.logger.info('DROPPING COLUMNS')
|
||||
payload.logger.info(dropColumnsStatement)
|
||||
}
|
||||
|
||||
await db.execute(sql.raw(dropColumnsStatement))
|
||||
// DROP TYPES
|
||||
await runStatementGroup({
|
||||
adapter,
|
||||
db,
|
||||
debug: debug ? 'DROPPING TYPES' : null,
|
||||
statements: sqlUpStatements.dropType,
|
||||
})
|
||||
}
|
||||
|
||||
@@ -56,7 +56,7 @@ export const migrateRelationships = async ({
|
||||
${where} ORDER BY parent_id LIMIT 500 OFFSET ${offset * 500};
|
||||
`
|
||||
|
||||
paginationResult = await adapter.drizzle.execute(sql.raw(`${paginationStatement}`))
|
||||
paginationResult = await db.execute(sql.raw(`${paginationStatement}`))
|
||||
|
||||
if (paginationResult.rows.length === 0) {
|
||||
return
|
||||
@@ -72,7 +72,7 @@ export const migrateRelationships = async ({
|
||||
payload.logger.info(statement)
|
||||
}
|
||||
|
||||
const result = await adapter.drizzle.execute(sql.raw(`${statement}`))
|
||||
const result = await db.execute(sql.raw(`${statement}`))
|
||||
|
||||
const docsToResave: DocsToResave = {}
|
||||
|
||||
|
||||
Reference in New Issue
Block a user