From 13e185d059dc826d903ef6bb33428b0c452a1b91 Mon Sep 17 00:00:00 2001 From: Nathan Woltman Date: Thu, 9 May 2019 15:08:59 -0400 Subject: [PATCH] feat: Add support for key prefix lengths --- README.md | 41 ++++++++++++++++--- jsdoc2md/README.hbs | 41 ++++++++++++++++--- lib/KeyDefinitions/IndexKeyDefinition.js | 12 +++--- lib/KeyDefinitions/PrimaryKeyDefinition.js | 12 +++--- lib/TableDefinition.js | 33 +++++++-------- lib/sqlToSchema.js | 12 +++--- lib/utils/parseKeyParts.js | 44 ++++++++++++++++++++ test/integration/MySQLPlus.test.js | 47 ++++++++++++++++++++++ test/unit/KeyDefinitions.test.js | 40 +++++++++++++++++- test/unit/parseKeyParts.test.js | 24 +++++++++++ 10 files changed, 258 insertions(+), 48 deletions(-) create mode 100644 lib/utils/parseKeyParts.js create mode 100644 test/unit/parseKeyParts.test.js diff --git a/README.md b/README.md index fa2d41a..990e461 100644 --- a/README.md +++ b/README.md @@ -1125,9 +1125,9 @@ See the [Column Types](#column-types) section for all possible column types and ### Primary Key -`string|string[]` +`string | string[]` -The table’s primary key can be defined with the `primaryKey` property: +The table’s primary key can be defined with the `primaryKey` property. ```js { @@ -1151,6 +1151,17 @@ An array can be used to define a multi-column primary key. } ``` +Primary keys for string columns may include a key [prefix length](#prefix-lengths). + +```js +{ + columns: { + id: pool.ColTypes.varchar(100).unsigned().notNull(), + }, + primaryKey: 'id(20)' +} +``` + ### Keys Keys can be defined with the `keys` property, which is an array of [`KeyTypes`](#key-types): @@ -1395,10 +1406,10 @@ Compatible types: [`mysql.KeyTypes`](#module_mysql-plus..KeyTypes) and [`pool.KeyTypes`](#PoolPlus+KeyTypes) both expose the following methods for defining table keys: -+ `index(columnName [, ...otherColumns])` - Creates a regular [index](https://dev.mysql.com/doc/en/create-index.html) -+ `uniqueIndex(columnName [, ...otherColumns])` - Creates a [unique index](https://dev.mysql.com/doc/en/create-index.html#create-index-unique) ++ `index(keyPart [, ...otherKeyParts])` - Creates a regular [index](https://dev.mysql.com/doc/en/create-index.html) ++ `uniqueIndex(keyPart [, ...otherKeyParts])` - Creates a [unique index](https://dev.mysql.com/doc/en/create-index.html#create-index-unique) + `spatialIndex(columnName)` - Creates a [spatial index](https://dev.mysql.com/doc/en/create-index.html#create-index-spatial) -+ `fulltextIndex(columnName)` - Creates a [fulltext index](https://dev.mysql.com/doc/en/innodb-fulltext-index.html) ++ `fulltextIndex(columnName, [...otherColumns])` - Creates a [fulltext index](https://dev.mysql.com/doc/en/innodb-fulltext-index.html) + `foreignKey(columnName [, ...otherColumns])` - Creates a [foreign key constraint](https://dev.mysql.com/doc/en/create-table-foreign-keys.html) **Example:** @@ -1473,4 +1484,22 @@ Indexes required for the example above: KeyTypes.index('thingOne', 'thingTwo'), ] } -``` \ No newline at end of file +``` + +### Prefix Lengths + +`PRIMARY`, `INDEX`, and `UNIQUE` keys on `char`, `varchar`, `binary`, `varbinary`, `blob`, and `text` columns may include a [key prefix length](https://dev.mysql.com/doc/en/create-index.html#create-index-column-prefixes). + +```js +{ + columns: { + id: ColTypes.char(50).notNull(), + uid: ColTypes.varchar(100).notNull(), + description: ColTypes.text(), + }, + primaryKey: 'id(10)', + keys: [ + KeyTypes.uniqueIndex('uid(30)'), + KeyTypes.index('description(50)'), + ] +``` diff --git a/jsdoc2md/README.hbs b/jsdoc2md/README.hbs index 3015d4e..5ec2871 100644 --- a/jsdoc2md/README.hbs +++ b/jsdoc2md/README.hbs @@ -166,9 +166,9 @@ See the [Column Types](#column-types) section for all possible column types and ### Primary Key -`string|string[]` +`string | string[]` -The table’s primary key can be defined with the `primaryKey` property: +The table’s primary key can be defined with the `primaryKey` property. ```js { @@ -192,6 +192,17 @@ An array can be used to define a multi-column primary key. } ``` +Primary keys for string columns may include a key [prefix length](#prefix-lengths). + +```js +{ + columns: { + id: pool.ColTypes.varchar(100).unsigned().notNull(), + }, + primaryKey: 'id(20)' +} +``` + ### Keys Keys can be defined with the `keys` property, which is an array of [`KeyTypes`](#key-types): @@ -436,10 +447,10 @@ Compatible types: [`mysql.KeyTypes`](#module_mysql-plus..KeyTypes) and [`pool.KeyTypes`](#PoolPlus+KeyTypes) both expose the following methods for defining table keys: -+ `index(columnName [, ...otherColumns])` - Creates a regular [index](https://dev.mysql.com/doc/en/create-index.html) -+ `uniqueIndex(columnName [, ...otherColumns])` - Creates a [unique index](https://dev.mysql.com/doc/en/create-index.html#create-index-unique) ++ `index(keyPart [, ...otherKeyParts])` - Creates a regular [index](https://dev.mysql.com/doc/en/create-index.html) ++ `uniqueIndex(keyPart [, ...otherKeyParts])` - Creates a [unique index](https://dev.mysql.com/doc/en/create-index.html#create-index-unique) + `spatialIndex(columnName)` - Creates a [spatial index](https://dev.mysql.com/doc/en/create-index.html#create-index-spatial) -+ `fulltextIndex(columnName)` - Creates a [fulltext index](https://dev.mysql.com/doc/en/innodb-fulltext-index.html) ++ `fulltextIndex(columnName, [...otherColumns])` - Creates a [fulltext index](https://dev.mysql.com/doc/en/innodb-fulltext-index.html) + `foreignKey(columnName [, ...otherColumns])` - Creates a [foreign key constraint](https://dev.mysql.com/doc/en/create-table-foreign-keys.html) **Example:** @@ -514,4 +525,22 @@ Indexes required for the example above: KeyTypes.index('thingOne', 'thingTwo'), ] } -``` \ No newline at end of file +``` + +### Prefix Lengths + +`PRIMARY`, `INDEX`, and `UNIQUE` keys on `char`, `varchar`, `binary`, `varbinary`, `blob`, and `text` columns may include a [key prefix length](https://dev.mysql.com/doc/en/create-index.html#create-index-column-prefixes). + +```js +{ + columns: { + id: ColTypes.char(50).notNull(), + uid: ColTypes.varchar(100).notNull(), + description: ColTypes.text(), + }, + primaryKey: 'id(10)', + keys: [ + KeyTypes.uniqueIndex('uid(30)'), + KeyTypes.index('description(50)'), + ] +``` diff --git a/lib/KeyDefinitions/IndexKeyDefinition.js b/lib/KeyDefinitions/IndexKeyDefinition.js index 629bf1f..9e00e43 100644 --- a/lib/KeyDefinitions/IndexKeyDefinition.js +++ b/lib/KeyDefinitions/IndexKeyDefinition.js @@ -2,12 +2,14 @@ const arraysEqual = require('../utils/arraysEqual'); const {escapeId} = require('mysql/lib/protocol/SqlString'); +const parseKeyParts = require('../utils/parseKeyParts'); class IndexKeyDefinition { - constructor(type, namePrefix, columns) { - this.$name = namePrefix + '_' + columns.join('_'); + constructor(type, namePrefix, keyParts) { + const {columnNames, formattedKeyParts} = parseKeyParts(keyParts); + this.$name = namePrefix + '_' + columnNames.join('_'); this._type = type; - this._columns = columns; + this._keyParts = formattedKeyParts; } name(name) { @@ -18,11 +20,11 @@ class IndexKeyDefinition { $equals(otherKey) { return this._type === otherKey._type && this.$name === otherKey.$name && - arraysEqual(this._columns, otherKey._columns); + arraysEqual(this._keyParts, otherKey._keyParts); } $toSQL() { - return `${this._type} ${escapeId(this.$name)} (${escapeId(this._columns)})`; + return `${this._type} ${escapeId(this.$name)} (${this._keyParts.join(', ')})`; } } diff --git a/lib/KeyDefinitions/PrimaryKeyDefinition.js b/lib/KeyDefinitions/PrimaryKeyDefinition.js index 6ad181b..da38b57 100644 --- a/lib/KeyDefinitions/PrimaryKeyDefinition.js +++ b/lib/KeyDefinitions/PrimaryKeyDefinition.js @@ -1,19 +1,21 @@ 'use strict'; const arraysEqual = require('../utils/arraysEqual'); -const {escapeId} = require('mysql/lib/protocol/SqlString'); +const parseKeyParts = require('../utils/parseKeyParts'); class PrimaryKeyDefinition { - constructor(columns) { - this._columns = columns; + constructor(keyParts) { + const {columnNames, formattedKeyParts} = parseKeyParts(keyParts); + this.$columnNames = columnNames; + this._keyParts = formattedKeyParts; } $equals(otherKey) { - return arraysEqual(this._columns, otherKey._columns); + return arraysEqual(this._keyParts, otherKey._keyParts); } $toSQL() { - return `PRIMARY KEY (${escapeId(this._columns)})`; + return `PRIMARY KEY (${this._keyParts.join(', ')})`; } } diff --git a/lib/TableDefinition.js b/lib/TableDefinition.js index a3f20d8..d320c22 100644 --- a/lib/TableDefinition.js +++ b/lib/TableDefinition.js @@ -130,7 +130,6 @@ class TableDefinition { `CHANGE COLUMN ${pool.escapeId(oldColumnName)} ${pool.escapeId(columnName)} ` + newColumnDefinition.$toSQL() + position )); - renamedColumns.push(oldColumnName); } else if (!newColumnDefinition.$equals(oldColumnDefinition, oldSchema)) { operations.push(Operation.create( @@ -390,14 +389,14 @@ function createInternalSchema(schema, tableName) { } } - let primaryKey = null; + let columnPK = null; // Extract keys defined in the columns for (const columnName in columns) { const column = columns[columnName]; if (column.$primaryKey) { - primaryKey = columnName; + columnPK = columnName; } if (column.$unique) { const key = KeyDefinitions.uniqueIndex(columnName); @@ -417,24 +416,20 @@ function createInternalSchema(schema, tableName) { } } - if (schema.primaryKey) { + let primaryKey = null; + + if (schema.primaryKey) { // The primaryKey in the schema takes precedence over one defined by a column + if (typeof schema.primaryKey === 'string') { + primaryKey = new PrimaryKeyDefinition([schema.primaryKey]); + } else { // schema.primaryKey is an Array + primaryKey = new PrimaryKeyDefinition(schema.primaryKey); + } // Make sure primary key columns are not null - if (Array.isArray(schema.primaryKey)) { - for (const colName of schema.primaryKey) { - columns[colName].notNull(); - } - } else { - columns[schema.primaryKey].notNull(); + for (const colName of primaryKey.$columnNames) { + columns[colName].notNull(); } - - // The primaryKey in the schema takes precedence over one defined by a column - primaryKey = schema.primaryKey; - } - - if (typeof primaryKey === 'string') { - primaryKey = new PrimaryKeyDefinition([primaryKey]); - } else if (Array.isArray(primaryKey)) { - primaryKey = new PrimaryKeyDefinition(primaryKey); + } else if (columnPK !== null) { + primaryKey = new PrimaryKeyDefinition([columnPK]); } return Object.assign({}, schema, {primaryKey, indexKeys, foreignKeys}); diff --git a/lib/sqlToSchema.js b/lib/sqlToSchema.js index b853b9d..4be5c29 100644 --- a/lib/sqlToSchema.js +++ b/lib/sqlToSchema.js @@ -150,20 +150,20 @@ function generateColumnsSchema(createDefinitions) { } function columnsSQLToSchema(sql) { - return sql.replace(/`|\s/g, '').split(','); + return sql.replace(/`/g, '').split(/,\s*/); } function generatePrimaryKeySchema(keySQL) { - const pkMatch = /^\s*PRIMARY KEY \((.*?)\)/.exec(keySQL); + const pkMatch = /^\s*PRIMARY KEY \((.*)\)/.exec(keySQL); return pkMatch === null ? null : new PrimaryKeyDefinition(columnsSQLToSchema(pkMatch[1])); } -const rgxUniqueKey = /^\s*UNIQUE KEY `(\w+)` \((.*?)\)/; -const rgxIndexKey = /^\s*KEY `(\w+)` \((.*?)\)/; -const rgxSpatialKey = /^\s*SPATIAL KEY `(\w+)` \((.*?)\)/; -const rgxFulltextKey = /^\s*FULLTEXT KEY `(\w+)` \((.*?)\)/; +const rgxUniqueKey = /^\s*UNIQUE KEY `(\w+)` \((.*)\)/; +const rgxIndexKey = /^\s*KEY `(\w+)` \((.*)\)/; +const rgxSpatialKey = /^\s*SPATIAL KEY `(\w+)` \((.*)\)/; +const rgxFulltextKey = /^\s*FULLTEXT KEY `(\w+)` \((.*)\)/; const rgxForeignKey = /\s*CONSTRAINT `(\w+)` FOREIGN KEY \(`(.*?)`\) REFERENCES `(\w+)` \(`(.*?)`\)(?: ON DELETE (RESTRICT|CASCADE|SET NULL|NO ACTION))?(?: ON UPDATE (RESTRICT|CASCADE|SET NULL|NO ACTION))?/; diff --git a/lib/utils/parseKeyParts.js b/lib/utils/parseKeyParts.js new file mode 100644 index 0000000..2e1d69e --- /dev/null +++ b/lib/utils/parseKeyParts.js @@ -0,0 +1,44 @@ +'use strict'; + +const {escapeId} = require('mysql/lib/protocol/SqlString'); + +function parseKeyParts(keyParts) { + const columnNames = []; + const formattedKeyParts = []; + + for (let i = 0; i < keyParts.length; i++) { + const parsedKeyPart = parseKeyPart(keyParts[i]); + + columnNames.push(parsedKeyPart.column); + formattedKeyParts.push(formatKeyPart(parsedKeyPart)); + } + + return {columnNames, formattedKeyParts}; +} + +const rgxKeyPart = /^(\w+)(?:\s*\((\d+)\))?(?:\s+(ASC|DESC))?/i; + +function parseKeyPart(keyPart) { + const match = rgxKeyPart.exec(keyPart); + + if (match === null) { + throw new Error('Invalid key part: ' + keyPart); + } + + return { + column: match[1], + length: match[2], + }; +} + +function formatKeyPart(keyPart) { + let sql = escapeId(keyPart.column); + + if (keyPart.length !== undefined) { + sql += `(${keyPart.length})`; + } + + return sql; +} + +module.exports = parseKeyParts; diff --git a/test/integration/MySQLPlus.test.js b/test/integration/MySQLPlus.test.js index fa26d5f..b1e6a98 100644 --- a/test/integration/MySQLPlus.test.js +++ b/test/integration/MySQLPlus.test.js @@ -557,6 +557,29 @@ describe('MySQLPlus', function() { ' `e` char(1) CHARACTER SET utf8mb4 COLLATE utf8mb4_bin DEFAULT NULL\n' + ') ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_520_ci'; + const keyPartsTableName = 'key_parts_table'; + const keyPartsTableSchema = { + columns: { + a: ColTypes.char(7).notNull(), + b: ColTypes.varchar(30), + c: ColTypes.text(), + }, + primaryKey: 'a(5)', + keys: [ + KeyTypes.index('b(20)'), + KeyTypes.uniqueIndex('c(42)'), + ], + }; + const keyPartsTableExpectedSQL = + 'CREATE TABLE `key_parts_table` (\n' + + ' `a` char(7) NOT NULL,\n' + + ' `b` varchar(30) DEFAULT NULL,\n' + + ' `c` text,\n' + + ' PRIMARY KEY (`a`(5)),\n' + + ' UNIQUE KEY `uniq_c` (`c`(42)),\n' + + ' KEY `idx_b` (`b`(20))\n' + + ') ENGINE=InnoDB DEFAULT CHARSET=utf8'; + const timestampTableName = 'timestamp_table'; const timestampTableSchema = { columns: { @@ -615,6 +638,7 @@ describe('MySQLPlus', function() { pool.defineTable(foreignKeysTableName, foreignKeysTableSchema); pool.defineTable(optionsTableName, optionsTableSchema); pool.defineTable(textTableName, textTableSchema); + pool.defineTable(keyPartsTableName, keyPartsTableSchema); pool.defineTable(timestampTableName, timestampTableSchema); pool.defineTable(synonymTableName, synonymTableSchema); pool.sync(done); @@ -711,6 +735,13 @@ describe('MySQLPlus', function() { cb10(); }); + const cbKeyParts = cbManager.registerCallback(); + pool.query(`SHOW CREATE TABLE \`${keyPartsTableName}\``, (err, result) => { + if (err) throw err; + result[0]['Create Table'].should.equal(keyPartsTableExpectedSQL); + cbKeyParts(); + }); + const cbTimestamp = cbManager.registerCallback(); pool.query(`SHOW CREATE TABLE \`${timestampTableName}\``, (err, result) => { if (err) throw err; @@ -747,6 +778,7 @@ describe('MySQLPlus', function() { pool.defineTable(foreignKeysTableName, foreignKeysTableSchema); pool.defineTable(optionsTableName, optionsTableSchema); pool.defineTable(textTableName, textTableSchema); + pool.defineTable(keyPartsTableName, keyPartsTableSchema); pool.defineTable(timestampTableName, timestampTableSchema); pool.defineTable(synonymTableName, synonymTableSchema); pool.sync(done); @@ -848,6 +880,13 @@ describe('MySQLPlus', function() { cb10(); }); + const cbKeyParts = cbManager.registerCallback(); + pool.query(`SHOW CREATE TABLE \`${keyPartsTableName}\``, (err, result) => { + if (err) throw err; + result[0]['Create Table'].should.equal(keyPartsTableExpectedSQL); + cbKeyParts(); + }); + const cbTimestamp = cbManager.registerCallback(); pool.query(`SHOW CREATE TABLE \`${timestampTableName}\``, (err, result) => { if (err) throw err; @@ -884,6 +923,7 @@ describe('MySQLPlus', function() { pool.defineTable(foreignKeysTableName, foreignKeysTableSchema); pool.defineTable(optionsTableName, optionsTableSchema); pool.defineTable(textTableName, textTableSchema); + pool.defineTable(keyPartsTableName, keyPartsTableSchema); pool.defineTable(timestampTableName, timestampTableSchema); pool.defineTable(synonymTableName, synonymTableSchema); pool.sync(done); @@ -980,6 +1020,13 @@ describe('MySQLPlus', function() { cb10(); }); + const cbKeyParts = cbManager.registerCallback(); + pool.query(`SHOW CREATE TABLE \`${keyPartsTableName}\``, (err, result) => { + if (err) throw err; + result[0]['Create Table'].should.equal(keyPartsTableExpectedSQL); + cbKeyParts(); + }); + const cbTimestamp = cbManager.registerCallback(); pool.query(`SHOW CREATE TABLE \`${timestampTableName}\``, (err, result) => { if (err) throw err; diff --git a/test/unit/KeyDefinitions.test.js b/test/unit/KeyDefinitions.test.js index 05d4fb8..e39e977 100644 --- a/test/unit/KeyDefinitions.test.js +++ b/test/unit/KeyDefinitions.test.js @@ -284,9 +284,47 @@ describe('KeyDefinitions', () => { a = KeyDefinitions.foreignKey('a').references('t', 'id').cascade(); b = KeyDefinitions.foreignKey('a').references('t', 'id').onDelete('SET NULL').onUpdate('CASCADE'); a.$equals(b).should.be.false(); + + // More for keys with a prefix length + + a = KeyDefinitions.index('a(20)'); + b = KeyDefinitions.index('a(20)'); + a.$equals(b).should.be.true(); + + a = KeyDefinitions.uniqueIndex('a(20)'); + b = KeyDefinitions.uniqueIndex('a(20)'); + a.$equals(b).should.be.true(); + + a = KeyDefinitions.index('a(20)'); + b = KeyDefinitions.index('a(10)'); + a.$equals(b).should.be.false(); + + a = KeyDefinitions.uniqueIndex('a(20)'); + b = KeyDefinitions.uniqueIndex('a(10)'); + a.$equals(b).should.be.false(); + + a = KeyDefinitions.index('a(20)'); + b = KeyDefinitions.index('b(20)'); + a.$equals(b).should.be.false(); + + a = KeyDefinitions.uniqueIndex('a(20)'); + b = KeyDefinitions.uniqueIndex('b(20)'); + a.$equals(b).should.be.false(); }); - it('should support key prefixes'); + it('should support keys with a prefix length', () => { + KeyDefinitions.index('id(20)').$toSQL() + .should.equal('INDEX `idx_id` (`id`(20))'); + + KeyDefinitions.uniqueIndex('id(20)').$toSQL() + .should.equal('UNIQUE INDEX `uniq_id` (`id`(20))'); + + KeyDefinitions.index('id(20)', 'name(5)').$toSQL() + .should.equal('INDEX `idx_id_name` (`id`(20), `name`(5))'); + + KeyDefinitions.uniqueIndex('id(20)', 'name(5)').$toSQL() + .should.equal('UNIQUE INDEX `uniq_id_name` (`id`(20), `name`(5))'); + }); describe('foreign key definitions', () => { diff --git a/test/unit/parseKeyParts.test.js b/test/unit/parseKeyParts.test.js new file mode 100644 index 0000000..53575cf --- /dev/null +++ b/test/unit/parseKeyParts.test.js @@ -0,0 +1,24 @@ +'use strict'; + +const parseKeyParts = require('../../lib/utils/parseKeyParts'); +const should = require('should'); + +describe('parseKeyParts', () => { + + it('should parse key parts', () => { + parseKeyParts(['id']).should.deepEqual({ + columnNames: ['id'], + formattedKeyParts: ['`id`'], + }); + + parseKeyParts(['id', 'name(5)']).should.deepEqual({ + columnNames: ['id', 'name'], + formattedKeyParts: ['`id`', '`name`(5)'], + }); + }); + + it('should throw if passed invalid key parts', () => { + should.throws(() => parseKeyParts(['(nope)']), /Invalid key part/); + }); + +});