diff --git a/README.md b/README.md index 4792b6f..946cbb4 100644 --- a/README.md +++ b/README.md @@ -670,7 +670,9 @@ Only allows newly-defined tables to be created. Existing tables are never altere Specifies that newly-defined tables will be created, existing tables that are no longer defined will be dropped, and existing tables that have a different definition from what is found in the database will be migrated with minimal data-loss. -**Note:** The migration cannot always retain data. Currently, the only known example is that renaming a column will not preserve its data (and it's possible that there are others). For this reason, and the fact that there is no reasonable way to test how well the migration will work on a live production database, using the `alter` strategy in production is discouraged. +**When renaming table columns**, you must specify the column's old name in the [column definition](#columndefinition) with the `.oldName('name')` method. If you don't, the column will be dropped and you will lose all of the data that was in that column. + +**Note:** It is up to you to understand how changes to an existing table might affect the data. For example, changing a BIGINT column to a MEDIUMINT will cause integers greater than what can fit into a MEDIUMINT to wrap around and essentially become a different value (and you won't be able to recover the original value). Furthermore, some changes to tables cannot be done and will cause an error. An example of this would be adding a column with the `NOT NULL` attribute to a non-empty table without specifying a default value. #### drop @@ -886,6 +888,7 @@ This class is what is used to define the column's attributes. These attributes c + `primaryKey()` - Declares the column to be the table's primary key + `unique()` - Declares the column as a unique index + `index()` - Declares the column as an index ++ `oldName(name: string)` - The previous/current column name. If a column with this name exists, it will be renamed to the column name associated with the column defintion so that the data in that column will not be lost. All `ColumnDefinition` methods return the `ColumnDefinition`, so they are chainable. diff --git a/jsdoc2md/README.hbs b/jsdoc2md/README.hbs index 36cf6b1..44ff7a5 100644 --- a/jsdoc2md/README.hbs +++ b/jsdoc2md/README.hbs @@ -126,7 +126,9 @@ Only allows newly-defined tables to be created. Existing tables are never altere Specifies that newly-defined tables will be created, existing tables that are no longer defined will be dropped, and existing tables that have a different definition from what is found in the database will be migrated with minimal data-loss. -**Note:** The migration cannot always retain data. Currently, the only known example is that renaming a column will not preserve its data (and it's possible that there are others). For this reason, and the fact that there is no reasonable way to test how well the migration will work on a live production database, using the `alter` strategy in production is discouraged. +**When renaming table columns**, you must specify the column's old name in the [column definition](#columndefinition) with the `.oldName('name')` method. If you don't, the column will be dropped and you will lose all of the data that was in that column. + +**Note:** It is up to you to understand how changes to an existing table might affect the data. For example, changing a BIGINT column to a MEDIUMINT will cause integers greater than what can fit into a MEDIUMINT to wrap around and essentially become a different value (and you won't be able to recover the original value). Furthermore, some changes to tables cannot be done and will cause an error. An example of this would be adding a column with the `NOT NULL` attribute to a non-empty table without specifying a default value. #### drop @@ -342,6 +344,7 @@ This class is what is used to define the column's attributes. These attributes c + `primaryKey()` - Declares the column to be the table's primary key + `unique()` - Declares the column as a unique index + `index()` - Declares the column as an index ++ `oldName(name: string)` - The previous/current column name. If a column with this name exists, it will be renamed to the column name associated with the column defintion so that the data in that column will not be lost. All `ColumnDefinition` methods return the `ColumnDefinition`, so they are chainable. diff --git a/lib/ColumnDefinitions/ColumnDefinition.js b/lib/ColumnDefinitions/ColumnDefinition.js index f45392e..244bf20 100644 --- a/lib/ColumnDefinitions/ColumnDefinition.js +++ b/lib/ColumnDefinitions/ColumnDefinition.js @@ -22,6 +22,7 @@ class ColumnDefinition { this.$primaryKey = false; this.$unique = false; this.$index = false; + this.$oldName = null; this._notNull = false; this._default = undefined; } @@ -71,6 +72,11 @@ class ColumnDefinition { return this; } + oldName(oldName) { + this.$oldName = oldName; + return this; + } + $equals(columnDefinition) { var thisType = this.$type; var otherType = columnDefinition.$type; @@ -96,6 +102,7 @@ class ColumnDefinition { return (this._default === 'NULL' || this._default === undefined) && (columnDefinition._default === 'NULL' || columnDefinition._default === undefined); // Don't need to worry about keys since those are handled on the schema body + // The old column name also does not contribute to the equality of the column definitions } $toSQL() { diff --git a/lib/Operation.js b/lib/Operation.js index 1209750..7dc2f5f 100644 --- a/lib/Operation.js +++ b/lib/Operation.js @@ -10,9 +10,10 @@ const Operation = { DROP_COLUMN: 5, MODIFY_TABLE_OPTIONS: 6, MODIFY_COLUMN: 7, - ADD_COLUMN: 8, - ADD_KEY: 9, - ADD_FOREIGN_KEY: 10, + CHANGE_COLUMN: 8, + ADD_COLUMN: 9, + ADD_KEY: 10, + ADD_FOREIGN_KEY: 11, }, create(type, sql) { diff --git a/lib/TableDefinition.js b/lib/TableDefinition.js index cbaa270..9ace263 100644 --- a/lib/TableDefinition.js +++ b/lib/TableDefinition.js @@ -101,41 +101,54 @@ class TableDefinition { } _getMigrateColumnsOperations(oldSchema) { - const operations = []; + const pool = this._pool; + const escapedName = this._escapedName; const newSchema = this._schema; + const operations = []; + const renamedColumns = []; // List of old column names var columnName; - // Drop old columns - for (columnName in oldSchema.columns) { - if (newSchema.columns[columnName]) { - continue; - } - operations.push(Operation.create( - Operation.Types.DROP_COLUMN, - 'ALTER TABLE ' + this._escapedName + ' DROP COLUMN ' + this._pool.escapeId(columnName) - )); - } - // Add new columns and modify existing columns for (columnName in newSchema.columns) { const newColumnDefinition = newSchema.columns[columnName]; - const oldColumnDefinition = oldSchema.columns[columnName]; + const oldColumnName = newColumnDefinition.$oldName && oldSchema.columns[newColumnDefinition.$oldName] + ? newColumnDefinition.$oldName + : columnName; + const oldColumnDefinition = oldSchema.columns[oldColumnName]; if (!oldColumnDefinition) { operations.push(Operation.create( Operation.Types.ADD_COLUMN, - 'ALTER TABLE ' + this._escapedName + ' ADD COLUMN ' + this._pool.escapeId(columnName) + + 'ALTER TABLE ' + escapedName + ' ADD COLUMN ' + pool.escapeId(columnName) + ' ' + newColumnDefinition.$toSQL() )); + } else if (columnName !== oldColumnName) { + operations.push(Operation.create( + Operation.Types.CHANGE_COLUMN, + `ALTER TABLE ${escapedName} CHANGE COLUMN ${pool.escapeId(oldColumnName)} ${pool.escapeId(columnName)} ` + + newColumnDefinition.$toSQL() + )); + renamedColumns.push(oldColumnName); } else if (!newColumnDefinition.$equals(oldColumnDefinition, oldSchema)) { operations.push(Operation.create( Operation.Types.MODIFY_COLUMN, - 'ALTER TABLE ' + this._escapedName + ' MODIFY COLUMN ' + this._pool.escapeId(columnName) + + 'ALTER TABLE ' + escapedName + ' MODIFY COLUMN ' + pool.escapeId(columnName) + ' ' + newColumnDefinition.$toSQL() )); } } + // Drop old columns (unless the column is being changed) + for (columnName in oldSchema.columns) { + if (newSchema.columns[columnName] || renamedColumns.indexOf(columnName) >= 0) { + continue; + } + operations.push(Operation.create( + Operation.Types.DROP_COLUMN, + 'ALTER TABLE ' + escapedName + ' DROP COLUMN ' + pool.escapeId(columnName) + )); + } + return operations; } diff --git a/test/integration/MySQLPlus.test.js b/test/integration/MySQLPlus.test.js index 29b656d..a57c801 100644 --- a/test/integration/MySQLPlus.test.js +++ b/test/integration/MySQLPlus.test.js @@ -125,21 +125,29 @@ describe('MySQLPlus', function() { const columnsTableName = 'columns_table'; const columnsTableSchema = { columns: { - id: ColTypes.int().unsigned().notNull().primaryKey().autoIncrement(), + id: ColTypes.int().unsigned().notNull().primaryKey(), uuid: ColTypes.char(44).unique(), email: ColTypes.char(255), fp: ColTypes.float(7, 4), dropme: ColTypes.blob(), + renameme: ColTypes.tinyint(), + changeme: ColTypes.tinyint(), + neverchange: ColTypes.tinyint().oldName('fake_column'), + norename: ColTypes.tinyint().oldName('fake_column'), }, indexes: ['email'], }; const columnsTableExpectedSQL = 'CREATE TABLE `columns_table` (\n' + - ' `id` int(10) unsigned NOT NULL AUTO_INCREMENT,\n' + + ' `id` int(10) unsigned NOT NULL,\n' + ' `uuid` char(44) DEFAULT NULL,\n' + ' `email` char(255) DEFAULT NULL,\n' + ' `fp` float(7,4) DEFAULT NULL,\n' + ' `dropme` blob,\n' + + ' `renameme` tinyint(4) DEFAULT NULL,\n' + + ' `changeme` tinyint(4) DEFAULT NULL,\n' + + ' `neverchange` tinyint(4) DEFAULT NULL,\n' + + ' `norename` tinyint(4) DEFAULT NULL,\n' + ' PRIMARY KEY (`id`),\n' + ' UNIQUE KEY `unique_columns_table_uuid` (`uuid`),\n' + ' KEY `index_columns_table_email` (`email`)\n' + @@ -147,20 +155,28 @@ describe('MySQLPlus', function() { const columnsTableMigratedSchema = { columns: { - id: ColTypes.bigint(5).unsigned().notNull().primaryKey().autoIncrement(), + id: ColTypes.bigint(5).unsigned().notNull().primaryKey(), uuid: ColTypes.char(44).unique(), email: ColTypes.varchar(255).notNull(), fp: ColTypes.float(8, 3), + renamed: ColTypes.tinyint().oldName('renameme'), + changed: ColTypes.smallint().oldName('changeme'), + neverchange: ColTypes.tinyint().oldName('fake_column'), + norename: ColTypes.smallint().oldName('fake_column'), added: ColTypes.text(), }, uniqueKeys: ['email'], }; const columnsTableMigratedExpectedSQL = 'CREATE TABLE `columns_table` (\n' + - ' `id` bigint(5) unsigned NOT NULL AUTO_INCREMENT,\n' + + ' `id` bigint(5) unsigned NOT NULL,\n' + ' `uuid` char(44) DEFAULT NULL,\n' + ' `email` varchar(255) NOT NULL,\n' + ' `fp` float(8,3) DEFAULT NULL,\n' + + ' `renamed` tinyint(4) DEFAULT NULL,\n' + + ' `changed` smallint(6) DEFAULT NULL,\n' + + ' `neverchange` tinyint(4) DEFAULT NULL,\n' + + ' `norename` smallint(6) DEFAULT NULL,\n' + ' `added` text,\n' + ' PRIMARY KEY (`id`),\n' + ' UNIQUE KEY `unique_columns_table_email` (`email`),\n' + @@ -727,7 +743,16 @@ describe('MySQLPlus', function() { pool.defineTable(indexesTableName, indexesTableMigragedSchema); pool.defineTable(foreignKeysTableName, foreignKeysTableMigratedSchema); pool.defineTable(optionsTableName, optionsTableMigratedSchema); - pool.sync(done); + + // Insert data into the columns table before syncing the table changes so + // we can check if the data is still there after some columns get renamed + pool.query( + `INSERT INTO ${columnsTableName} (id, email, renameme, changeme) VALUES (1, 'a', 1, 2), (2, 'b', 3, 4)`, + err => { + if (err) throw err; + pool.sync(done); + } + ); }); after(done => { @@ -817,6 +842,22 @@ describe('MySQLPlus', function() { }); }); + it('should not lose data when renaming columns', done => { + pool.query(`SELECT renamed, changed FROM ${columnsTableName}`, (err, rows) => { + if (err) throw err; + + rows.length.should.equal(2); + + rows[0].renamed.should.equal(1); + rows[0].changed.should.equal(2); + + rows[1].renamed.should.equal(3); + rows[1].changed.should.equal(4); + + done(); + }); + }); + }); }); diff --git a/test/unit/ColumnDefinitions.test.js b/test/unit/ColumnDefinitions.test.js index 4062b52..8ac8cc9 100644 --- a/test/unit/ColumnDefinitions.test.js +++ b/test/unit/ColumnDefinitions.test.js @@ -152,6 +152,12 @@ describe('ColumnDefinitions', () => { b = ColumnDefinitions.int(); a.$equals(b).should.be.true(); b.$equals(a).should.be.true(); + + // Setting an old name doesn't affect equality + a = ColumnDefinitions.int().oldName('old_a'); + b = ColumnDefinitions.int().oldName('old_b'); + a.$equals(b).should.be.true(); + b.$equals(a).should.be.true(); }); @@ -447,6 +453,20 @@ describe('ColumnDefinitions', () => { cd.$toSQL().should.equal('blob NOT NULL'); }); + it('should allow columns to have their old column name specified but not change the SQL', () => { + ColumnDefinitions.int().oldName('old').$toSQL() + .should.equal(ColumnDefinitions.int().$toSQL()); + + ColumnDefinitions.char().oldName('old').$toSQL() + .should.equal(ColumnDefinitions.char().$toSQL()); + + ColumnDefinitions.blob().oldName('old').$toSQL() + .should.equal(ColumnDefinitions.blob().$toSQL()); + + ColumnDefinitions.timestamp().oldName('old').$toSQL() + .should.equal(ColumnDefinitions.timestamp().$toSQL()); + }); + });