Skip to content

Instantly share code, notes, and snippets.

@renatoaraujoc
Last active September 27, 2019 19:09
Show Gist options
  • Star 1 You must be signed in to star a gist
  • Fork 0 You must be signed in to fork a gist
  • Save renatoaraujoc/fe80c5531c8c8a0506d40f376e5a7eb0 to your computer and use it in GitHub Desktop.
Save renatoaraujoc/fe80c5531c8c8a0506d40f376e5a7eb0 to your computer and use it in GitHub Desktop.
Modify MySQL Table ID DataType with FKs
SET global group_concat_max_len = 4294967295;
SET @tableSchema = "SCHEMA_HERE";
SET @tableName = "TABLE_HERE";
SET @tablePrimaryDefinition = "int(10) unsigned not null auto_increment";
SET @referencedTablesColumnDefinition = "int(10) unsigned";
SELECT DISTINCT kcu.TABLE_NAME,
kcu.TABLE_SCHEMA,
kcu.COLUMN_NAME,
kcu.CONSTRAINT_NAME,
kcu.REFERENCED_TABLE_NAME,
kcu.REFERENCED_COLUMN_NAME,
kcu.REFERENCED_TABLE_SCHEMA,
cRef.UPDATE_RULE,
cRef.DELETE_RULE,
CONCAT(CONCAT('SET GLOBAL FOREIGN_KEY_CHECKS = 0'),
';',
GROUP_CONCAT(DISTINCT 'ALTER TABLE ', kcu.TABLE_SCHEMA, '.', kcu.TABLE_NAME, ' DROP FOREIGN KEY ', kcu.CONSTRAINT_NAME SEPARATOR ';'),
';',
GROUP_CONCAT(DISTINCT 'ALTER TABLE ', kcu.TABLE_SCHEMA, '.', kcu.TABLE_NAME, ' CHANGE ', kcu.COLUMN_NAME, ' ', kcu.COLUMN_NAME, ' ', @referencedTablesColumnDefinition SEPARATOR ';'),
';',
CONCAT('ALTER TABLE ', @tableSchema, '.', @tableName, ' CHANGE ', kcu.REFERENCED_COLUMN_NAME, ' ', kcu.REFERENCED_COLUMN_NAME, ' ', @tablePrimaryDefinition),
';',
GROUP_CONCAT(DISTINCT 'ALTER TABLE ', kcu.TABLE_SCHEMA, '.', kcu.TABLE_NAME, ' ADD CONSTRAINT ', kcu.CONSTRAINT_NAME, ' FOREIGN KEY(', kcu.COLUMN_NAME,') REFERENCES ', kcu.REFERENCED_TABLE_SCHEMA, '.', kcu.REFERENCED_TABLE_NAME, '(', kcu.REFERENCED_COLUMN_NAME, ') ON DELETE ', cRef.DELETE_RULE, ' ON UPDATE ', cRef.UPDATE_RULE SEPARATOR ';'),
';',
CONCAT('SET GLOBAL FOREIGN_KEY_CHECKS = 1')
) AS query
FROM information_schema.KEY_COLUMN_USAGE AS kcu
JOIN information_schema.referential_constraints AS cRef ON ( cRef.CONSTRAINT_NAME = kcu.CONSTRAINT_NAME )
WHERE kcu.referenced_table_name IS NOT NULL
AND kcu.REFERENCED_COLUMN_NAME IS NOT NULL
AND kcu.REFERENCED_TABLE_SCHEMA = @tableSchema
AND kcu.REFERENCED_TABLE_NAME = @tableName
GROUP BY kcu.REFERENCED_TABLE_NAME
@renatoaraujoc
Copy link
Author

renatoaraujoc commented Sep 27, 2019

This SQL code will generate a query to update a table primary key definition, i.e.:
test_table.id BIG INT (20) NOT NULL AUTO INCREMENT to test_table.id INT(10) NOT NULL AUTO INCREMENT

How to use:

  1. Change @tableSchema and @tableName to your requirements
  2. Execute the query
  3. Copy the generated query at the query column
  4. Execute the generated query
  5. See the magic happen!

What happens under the hood:

  1. Generates the DROP FOREIGN KEY commands for all references
  2. Change all column references to the target table with @referencedTablesColumnDefinition
  3. Updates table's primary key with @tablePrimaryDefinition
  4. Re-add all the foreign keys previously removed with ADD CONSTRAINT commands

The SET GLOBAL FOREIGN_KEY_CHECKS = 0/1 is necessary to avoid interruption of script because of data integrity errors.

Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment