diff --git a/lib/dialects/mssql/schema/mssql-columncompiler.js b/lib/dialects/mssql/schema/mssql-columncompiler.js index 4f6e10bff6..6ff74ace83 100644 --- a/lib/dialects/mssql/schema/mssql-columncompiler.js +++ b/lib/dialects/mssql/schema/mssql-columncompiler.js @@ -126,12 +126,22 @@ class ColumnCompiler_MSSQL extends ColumnCompiler { }); return ''; } + + increments(options = { primaryKey: true }) { + return ( + 'int identity(1,1) not null' + + (this.tableCompiler._canBeAddPrimaryKey(options) ? ' primary key' : '') + ); + } + + bigincrements(options = { primaryKey: true }) { + return ( + 'bigint identity(1,1) not null' + + (this.tableCompiler._canBeAddPrimaryKey(options) ? ' primary key' : '') + ); + } } -ColumnCompiler_MSSQL.prototype.increments = ({ primaryKey = true } = {}) => - 'int identity(1,1) not null' + (primaryKey ? ' primary key' : ''); -ColumnCompiler_MSSQL.prototype.bigincrements = ({ primaryKey = true } = {}) => - 'bigint identity(1,1) not null' + (primaryKey ? ' primary key' : ''); ColumnCompiler_MSSQL.prototype.bigint = 'bigint'; ColumnCompiler_MSSQL.prototype.mediumint = 'int'; ColumnCompiler_MSSQL.prototype.smallint = 'smallint'; diff --git a/lib/dialects/mysql/schema/mysql-columncompiler.js b/lib/dialects/mysql/schema/mysql-columncompiler.js index c44af84f9b..840e5d014d 100644 --- a/lib/dialects/mysql/schema/mysql-columncompiler.js +++ b/lib/dialects/mysql/schema/mysql-columncompiler.js @@ -152,13 +152,30 @@ class ColumnCompiler_MySQL extends ColumnCompiler { collate(collation) { return collation && `collate '${collation}'`; } + + increments(options = { primaryKey: true }) { + return ( + 'int unsigned not null' + + // In MySQL autoincrement are always a primary key. If you already have a primary key, we + // initialize this column as classic int column then modify it later in table compiler + (this.tableCompiler._canBeAddPrimaryKey(options) + ? ' auto_increment primary key' + : '') + ); + } + + bigincrements(options = { primaryKey: true }) { + return ( + 'bigint unsigned not null' + + // In MySQL autoincrement are always a primary key. If you already have a primary key, we + // initialize this column as classic int column then modify it later in table compiler + (this.tableCompiler._canBeAddPrimaryKey(options) + ? ' auto_increment primary key' + : '') + ); + } } -ColumnCompiler_MySQL.prototype.increments = ({ primaryKey = true } = {}) => - 'int unsigned not null auto_increment' + (primaryKey ? ' primary key' : ''); -ColumnCompiler_MySQL.prototype.bigincrements = ({ primaryKey = true } = {}) => - 'bigint unsigned not null auto_increment' + - (primaryKey ? ' primary key' : ''); ColumnCompiler_MySQL.prototype.bigint = 'bigint'; ColumnCompiler_MySQL.prototype.mediumint = 'mediumint'; ColumnCompiler_MySQL.prototype.smallint = 'smallint'; diff --git a/lib/dialects/mysql/schema/mysql-tablecompiler.js b/lib/dialects/mysql/schema/mysql-tablecompiler.js index d3b512b370..eab7fc0ca6 100644 --- a/lib/dialects/mysql/schema/mysql-tablecompiler.js +++ b/lib/dialects/mysql/schema/mysql-tablecompiler.js @@ -253,11 +253,31 @@ class TableCompiler_MySQL extends TableCompiler { constraintName = constraintName ? this.formatter.wrap(constraintName) : this.formatter.wrap(`${this.tableNameRaw}_pkey`); + + const primaryCols = columns; + let incrementsCols = []; + if (this.grouped.columns) { + incrementsCols = this._getIncrementsColumnNames(); + if (incrementsCols) { + incrementsCols.forEach((c) => { + if (!primaryCols.includes(c)) { + primaryCols.unshift(c); + } + }); + } + } this.pushQuery( `alter table ${this.tableName()} add primary key ${constraintName}(${this.formatter.columnize( - columns + primaryCols )})` ); + if (incrementsCols.length) { + this.pushQuery( + `alter table ${this.tableName()} modify column ${this.formatter.columnize( + incrementsCols + )} int unsigned not null auto_increment` + ); + } } unique(columns, indexName) { diff --git a/lib/dialects/oracle/schema/internal/trigger.js b/lib/dialects/oracle/schema/internal/trigger.js index 859862a6df..d84ff933be 100644 --- a/lib/dialects/oracle/schema/internal/trigger.js +++ b/lib/dialects/oracle/schema/internal/trigger.js @@ -64,7 +64,7 @@ const trigger = { `PK_NAME VARCHAR(200); ` + `BEGIN` + ` EXECUTE IMMEDIATE ('CREATE SEQUENCE ${schemaQuoted}${sequenceNameQuoted}');` + - ` SELECT cols.column_name INTO PK_NAME` + + ` SELECT cols.column_name INTO PK_NAME` + // TODO : support autoincrement on table with multiple primary keys ` FROM all_constraints cons, all_cons_columns cols` + ` WHERE cons.constraint_type = 'P'` + ` AND cons.constraint_name = cols.constraint_name` + diff --git a/lib/dialects/oracle/schema/oracle-columncompiler.js b/lib/dialects/oracle/schema/oracle-columncompiler.js index 8482c12fd0..589301b4e4 100644 --- a/lib/dialects/oracle/schema/oracle-columncompiler.js +++ b/lib/dialects/oracle/schema/oracle-columncompiler.js @@ -15,14 +15,20 @@ class ColumnCompiler_Oracle extends ColumnCompiler { this.modifiers = ['defaultTo', 'checkIn', 'nullable', 'comment']; } - increments({ primaryKey = true } = {}) { + increments(options = { primaryKey: true }) { createAutoIncrementTriggerAndSequence(this); - return 'integer not null' + (primaryKey ? ' primary key' : ''); + return ( + 'integer not null' + + (this.tableCompiler._canBeAddPrimaryKey(options) ? ' primary key' : '') + ); } - bigincrements({ primaryKey = true } = {}) { + bigincrements(options = { primaryKey: true }) { createAutoIncrementTriggerAndSequence(this); - return 'number(20, 0) not null' + (primaryKey ? ' primary key' : ''); + return ( + 'number(20, 0) not null' + + (this.tableCompiler._canBeAddPrimaryKey(options) ? ' primary key' : '') + ); } floating(precision) { diff --git a/lib/dialects/oracle/schema/oracle-tablecompiler.js b/lib/dialects/oracle/schema/oracle-tablecompiler.js index 2dbe6944e5..8c953d4ded 100644 --- a/lib/dialects/oracle/schema/oracle-tablecompiler.js +++ b/lib/dialects/oracle/schema/oracle-tablecompiler.js @@ -85,10 +85,6 @@ class TableCompiler_Oracle extends TableCompiler { ); } - changeType() { - // alter table + table + ' modify ' + wrapped + '// type'; - } - _indexCommand(type, tableName, columns) { return this.formatter.wrap( utils.generateCombinedName(this.client.logger, type, tableName, columns) @@ -104,9 +100,21 @@ class TableCompiler_Oracle extends TableCompiler { constraintName = constraintName ? this.formatter.wrap(constraintName) : this.formatter.wrap(`${this.tableNameRaw}_pkey`); + const primaryCols = columns; + let incrementsCols = []; + if (this.grouped.columns) { + incrementsCols = this._getIncrementsColumnNames(); + if (incrementsCols) { + incrementsCols.forEach((c) => { + if (!primaryCols.includes(c)) { + primaryCols.unshift(c); + } + }); + } + } this.pushQuery( `alter table ${this.tableName()} add constraint ${constraintName} primary key (${this.formatter.columnize( - columns + primaryCols )})${deferrable}` ); } diff --git a/lib/dialects/postgres/schema/pg-columncompiler.js b/lib/dialects/postgres/schema/pg-columncompiler.js index 5fb7fa2580..c35472718a 100644 --- a/lib/dialects/postgres/schema/pg-columncompiler.js +++ b/lib/dialects/postgres/schema/pg-columncompiler.js @@ -100,12 +100,22 @@ class ColumnCompiler_PG extends ColumnCompiler { ); }, comment); } + + increments(options = { primaryKey: true }) { + return ( + 'serial' + + (this.tableCompiler._canBeAddPrimaryKey(options) ? ' primary key' : '') + ); + } + + bigincrements(options = { primaryKey: true }) { + return ( + 'bigserial' + + (this.tableCompiler._canBeAddPrimaryKey(options) ? ' primary key' : '') + ); + } } -ColumnCompiler_PG.prototype.bigincrements = ({ primaryKey = true } = {}) => - 'bigserial' + (primaryKey ? ' primary key' : ''); -ColumnCompiler_PG.prototype.increments = ({ primaryKey = true } = {}) => - 'serial' + (primaryKey ? ' primary key' : ''); ColumnCompiler_PG.prototype.bigint = 'bigint'; ColumnCompiler_PG.prototype.binary = 'bytea'; ColumnCompiler_PG.prototype.bool = 'boolean'; diff --git a/lib/dialects/sqlite3/schema/sqlite-columncompiler.js b/lib/dialects/sqlite3/schema/sqlite-columncompiler.js index 787830ba71..ede68dbaf0 100644 --- a/lib/dialects/sqlite3/schema/sqlite-columncompiler.js +++ b/lib/dialects/sqlite3/schema/sqlite-columncompiler.js @@ -26,5 +26,9 @@ ColumnCompiler_SQLite3.prototype.double = ColumnCompiler_SQLite3.prototype.floating = 'float'; ColumnCompiler_SQLite3.prototype.timestamp = 'datetime'; +// autoincrement without primary key is a syntax error in SQLite, so it's necessary +ColumnCompiler_SQLite3.prototype.increments = + ColumnCompiler_SQLite3.prototype.bigincrements = + 'integer not null primary key autoincrement'; module.exports = ColumnCompiler_SQLite3; diff --git a/lib/dialects/sqlite3/schema/sqlite-tablecompiler.js b/lib/dialects/sqlite3/schema/sqlite-tablecompiler.js index 2c8271f3f3..2bc5a06a5e 100644 --- a/lib/dialects/sqlite3/schema/sqlite-tablecompiler.js +++ b/lib/dialects/sqlite3/schema/sqlite-tablecompiler.js @@ -261,9 +261,14 @@ class TableCompiler_SQLite3 extends TableCompiler { if (constraintName) { constraintName = ' constraint ' + this.formatter.wrap(constraintName); } - return `,${constraintName} primary key (${this.formatter.columnize( - columns - )})`; + const needUniqueCols = + this.grouped.columns.filter((t) => t.builder._type === 'increments') + .length > 0; + // SQLite dont support autoincrement columns and composite primary keys (autoincrement is always primary key). + // You need to add unique index instead when you have autoincrement columns (https://stackoverflow.com/a/6154876/1535159) + return `,${constraintName} ${ + needUniqueCols ? 'unique' : 'primary key' + } (${this.formatter.columnize(columns)})`; } } diff --git a/lib/schema/columncompiler.js b/lib/schema/columncompiler.js index 56a35adf27..b949b4233e 100644 --- a/lib/schema/columncompiler.js +++ b/lib/schema/columncompiler.js @@ -134,6 +134,18 @@ class ColumnCompiler { defaultTo(value) { return `default ${formatDefault(value, this.type, this.client)}`; } + + increments(options = { primaryKey: true }) { + return ( + 'integer not null' + + (this.tableCompiler._canBeAddPrimaryKey(options) ? ' primary key' : '') + + ' autoincrement' + ); + } + + bigincrements(options = { primaryKey: true }) { + return this.increments(options); + } } ColumnCompiler.prototype.binary = 'blob'; @@ -149,10 +161,6 @@ ColumnCompiler.prototype.enu = 'varchar'; ColumnCompiler.prototype.bit = ColumnCompiler.prototype.json = 'text'; ColumnCompiler.prototype.uuid = ({ useBinaryUuid = false } = {}) => useBinaryUuid ? 'binary(16)' : 'char(36)'; -ColumnCompiler.prototype.increments = ({ primaryKey = true } = {}) => - 'integer not null' + (primaryKey ? ' primary key' : '') + ' autoincrement'; -ColumnCompiler.prototype.bigincrements = ({ primaryKey = true } = {}) => - 'integer not null' + (primaryKey ? ' primary key' : '') + ' autoincrement'; ColumnCompiler.prototype.integer = ColumnCompiler.prototype.smallint = ColumnCompiler.prototype.mediumint = diff --git a/lib/schema/tablecompiler.js b/lib/schema/tablecompiler.js index bd4dd73399..49bb607e4d 100644 --- a/lib/schema/tablecompiler.js +++ b/lib/schema/tablecompiler.js @@ -361,6 +361,23 @@ class TableCompiler { ).toLowerCase(); return this.formatter.wrap(indexName); } + + _getPrimaryKeys() { + return (this.grouped.alterTable || []) + .filter((a) => a.method === 'primary') + .flatMap((a) => a.args) + .flat(); + } + + _canBeAddPrimaryKey(options) { + return options.primaryKey && this._getPrimaryKeys().length === 0; + } + + _getIncrementsColumnNames() { + return this.grouped.columns + .filter((c) => c.builder._type === 'increments') + .map((c) => c.builder._args[0]); + } } TableCompiler.prototype.pushQuery = pushQuery; diff --git a/test/integration2/schema/primary-keys.spec.js b/test/integration2/schema/primary-keys.spec.js index fa8d5d4504..1de1612ba0 100644 --- a/test/integration2/schema/primary-keys.spec.js +++ b/test/integration2/schema/primary-keys.spec.js @@ -31,7 +31,7 @@ describe('Schema', () => { }); afterEach(async () => { - await knex.schema.dropTable('primary_table'); + await knex.schema.dropTableIfExists('primary_table'); }); describe('createPrimaryKey', () => { @@ -63,6 +63,103 @@ describe('Schema', () => { } }); + it('create multiple primary keys with increments on same column', async function () { + await knex.schema.dropTableIfExists('table_multiple_keys'); + await knex.schema.createTable('table_multiple_keys', function (t) { + t.primary(['id', 'second_id', 'other_col']); + t.string('second_id', 16).notNullable(); + t.integer('other_col').notNullable(); + t.increments('id'); + }); + await knex('table_multiple_keys').insert([ + { + second_id: 'abc', + other_col: 2, + }, + { + second_id: 'abc', + other_col: 3, + }, + ]); + expect(() => { + knex('table_multiple_keys').insert([ + { + id: 1, + second_id: 'abc', + other_col: 2, + }, + ]); + }).to.throw; + // It's always ok, the primary key is on three columns. + await knex('table_multiple_keys').insert([ + { + second_id: 'abc', + other_col: 2, + }, + { + second_id: 'abc', + other_col: 3, + }, + ]); + expect(() => { + knex('table_multiple_keys').insert([ + { + id: 4, + second_id: 'abc', + other_col: 3, + }, + ]); + }).to.throw; + }); + + it('create multiple primary keys with increments on other columns', async function () { + await knex.schema.dropTableIfExists('table_multiple_keys'); + await knex.schema.createTable('table_multiple_keys', function (t) { + t.primary(['second_id', 'other_col']); + t.string('second_id', 16).notNullable(); + t.integer('other_col').notNullable(); + t.increments('id'); + }); + await knex('table_multiple_keys').insert([ + { + second_id: 'abc', + other_col: 2, + }, + { + second_id: 'abc', + other_col: 3, + }, + ]); + expect(() => { + knex('table_multiple_keys').insert([ + { + second_id: 'abc', + other_col: 2, + }, + ]); + }).to.throw; + // It's always ok, the primary key is on three columns. + await knex('table_multiple_keys').insert([ + { + second_id: 'bcd', + other_col: 2, + }, + { + second_id: 'abc', + other_col: 4, + }, + ]); + expect(() => { + knex('table_multiple_keys').insert([ + { + id: 4, + second_id: 'abc', + other_col: 3, + }, + ]); + }).to.throw; + }); + it('creates a primary key with a custom constraint name', async function () { // CockroachDB 21.1 throws "(72): unimplemented: primary key dropped without subsequent addition of new primary key in same transaction" if (isCockroachDB(knex)) { diff --git a/test/unit/schema-builder/mysql.js b/test/unit/schema-builder/mysql.js index dbd8c7ac1f..00b7fcaa2f 100644 --- a/test/unit/schema-builder/mysql.js +++ b/test/unit/schema-builder/mysql.js @@ -68,13 +68,14 @@ module.exports = function (dialect) { .schemaBuilder() .createTable('users', function (table) { table.increments('id'); + // In MySQL a autoincrement column is always a primary key table.increments('other_id', { primaryKey: false }); }) .toSQL(); equal(1, tableSql.length); expect(tableSql[0].sql).to.equal( - 'create table `users` (`id` int unsigned not null auto_increment primary key, `other_id` int unsigned not null auto_increment)' + 'create table `users` (`id` int unsigned not null auto_increment primary key, `other_id` int unsigned not null)' ); }); @@ -665,13 +666,14 @@ module.exports = function (dialect) { tableSql = client .schemaBuilder() .table('users', function () { + // In MySQL a autoincrement column is always a primary key this.bigIncrements('id', { primaryKey: false }); }) .toSQL(); equal(1, tableSql.length); expect(tableSql[0].sql).to.equal( - 'alter table `users` add `id` bigint unsigned not null auto_increment' + 'alter table `users` add `id` bigint unsigned not null' ); }); diff --git a/test/unit/schema-builder/oracle.js b/test/unit/schema-builder/oracle.js index ca8eba8dad..ea5df40069 100644 --- a/test/unit/schema-builder/oracle.js +++ b/test/unit/schema-builder/oracle.js @@ -76,7 +76,7 @@ describe('Oracle SchemaBuilder', function () { table.increments('id', { primaryKey: false }); }); - equal(2, tableSql.toSQL().length); + expect(tableSql.toSQL().length).to.equal(2); expect(tableSql.toSQL()[0].sql).to.equal( 'begin execute immediate \'create table "users" ("id" integer not null)\'; exception when others then if sqlcode != -955 then raise; end if; end;' ); diff --git a/test/unit/schema-builder/sqlite3.js b/test/unit/schema-builder/sqlite3.js index 1333c39064..c071373708 100644 --- a/test/unit/schema-builder/sqlite3.js +++ b/test/unit/schema-builder/sqlite3.js @@ -214,15 +214,15 @@ describe('SQLite SchemaBuilder', function () { tableSql = client .schemaBuilder() .createTable('users', function (table) { - table.increments('id'); - table.increments('other_id', { primaryKey: false }); + // This make nothing in SQLite, autoincrement without primary key is a syntax error. + table.increments('id', { primaryKey: false }); }) .toSQL(); equal(1, tableSql.length); equal( tableSql[0].sql, - 'create table `users` (`id` integer not null primary key autoincrement, `other_id` integer not null autoincrement)' + 'create table `users` (`id` integer not null primary key autoincrement)' ); }); @@ -563,6 +563,7 @@ describe('SQLite SchemaBuilder', function () { tableSql = client .schemaBuilder() .table('users', function (table) { + // This make nothing in SQLite, autoincrement without primary key is a syntax error. table.bigIncrements('id', { primaryKey: false }); }) .toSQL(); @@ -570,7 +571,7 @@ describe('SQLite SchemaBuilder', function () { equal(1, tableSql.length); equal( tableSql[0].sql, - 'alter table `users` add column `id` integer not null autoincrement' + 'alter table `users` add column `id` integer not null primary key autoincrement' ); });