Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Add NULLS NOT DISTINCT #6054

Open
wants to merge 3 commits into
base: master
Choose a base branch
from
Open
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Jump to
Jump to file
Failed to load files.
Diff view
Diff view
4 changes: 2 additions & 2 deletions docs/src/guide/schema-builder.md
Expand Up @@ -747,9 +747,9 @@ If you want to chain primary() while creating new column you can use [primary](#

### unique

**table.unique(columns, options={[indexName: string], [deferrable:'not deferrable'|'immediate'|'deferred'], [storageEngineIndexType:'btree'|'hash'], [useConstraint:true|false], [predicate: QueryBuilder]})**
**table.unique(columns, options={[indexName: string], [deferrable:'not deferrable'|'immediate'|'deferred'], [storageEngineIndexType:'btree'|'hash'], [useConstraint:true|false], [predicate: QueryBuilder], [nullsNotDistinct: true|false]})**

Adds an unique index to a table over the given `columns`. In MySQL, the storage engine index type may be 'btree' or 'hash' index types, more info in Index Options section : [https://dev.mysql.com/doc/refman/8.0/en/create-index.html](https://dev.mysql.com/doc/refman/8.0/en/create-index.html). A default index name using the columns is used unless indexName is specified. If you need to create a composite index, pass an array of column to `columns`. Deferrable unique constraint are supported on Postgres and Oracle and can be set by passing deferrable option to options object. In MSSQL and Postgres, you can set the `useConstraint` option to true to create a unique constraint instead of a unique index (defaults to false for MSSQL, true for Postgres without `predicate`, false for Postgres with `predicate`). In PostgreSQL, SQLite and MSSQL a partial unique index can be specified by setting a 'where' predicate.
Adds an unique index to a table over the given `columns`. In MySQL, the storage engine index type may be 'btree' or 'hash' index types, more info in Index Options section : [https://dev.mysql.com/doc/refman/8.0/en/create-index.html](https://dev.mysql.com/doc/refman/8.0/en/create-index.html). A default index name using the columns is used unless indexName is specified. If you need to create a composite index, pass an array of column to `columns`. Deferrable unique constraint are supported on Postgres and Oracle and can be set by passing deferrable option to options object. In MSSQL and Postgres, you can set the `useConstraint` option to true to create a unique constraint instead of a unique index (defaults to false for MSSQL, true for Postgres without `predicate`, false for Postgres with `predicate`). In PostgreSQL, SQLite and MSSQL a partial unique index can be specified by setting a 'where' predicate. In Postgres 15+ specifying `nullsNotDistinct: true` on unique index will cause `NULL` to be treated as not distinct, or in other words, equivalently.

```js
knex.schema.alterTable('users', function (t) {
Expand Down
7 changes: 6 additions & 1 deletion lib/dialects/mssql/schema/mssql-tablecompiler.js
Expand Up @@ -287,8 +287,10 @@ class TableCompiler_MSSQL extends TableCompiler {
let deferrable;
let useConstraint = false;
let predicate;
let nullsNotDistinct;
if (isObject(indexName)) {
({ indexName, deferrable, useConstraint, predicate } = indexName);
({ indexName, deferrable, useConstraint, predicate, nullsNotDistinct } =
indexName);
}
if (deferrable && deferrable !== 'not deferrable') {
this.client.logger.warn(
Expand All @@ -298,6 +300,9 @@ class TableCompiler_MSSQL extends TableCompiler {
if (useConstraint && predicate) {
throw new Error('mssql cannot create constraint with predicate');
}
if (nullsNotDistinct !== undefined) {
Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

allow null as well

Suggested change
if (nullsNotDistinct !== undefined) {
if (nullsNotDistinct != null) {

throw new Error('mssql cannot make unique with nullsNotDistinct option');
}
indexName = indexName
? this.formatter.wrap(indexName)
: this._indexCommand('unique', this.tableNameRaw, columns);
Expand Down
7 changes: 6 additions & 1 deletion lib/dialects/mysql/schema/mysql-tablecompiler.js
Expand Up @@ -345,14 +345,19 @@ class TableCompiler_MySQL extends TableCompiler {
unique(columns, indexName) {
let storageEngineIndexType;
let deferrable;
let nullsNotDistinct;
if (isObject(indexName)) {
({ indexName, deferrable, storageEngineIndexType } = indexName);
({ indexName, deferrable, storageEngineIndexType, nullsNotDistinct } =
indexName);
}
if (deferrable && deferrable !== 'not deferrable') {
this.client.logger.warn(
`mysql: unique index \`${indexName}\` will not be deferrable ${deferrable} because mysql does not support deferred constraints.`
);
}
if (nullsNotDistinct !== undefined) {
Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

allow null as well

Suggested change
if (nullsNotDistinct !== undefined) {
if (nullsNotDistinct != null) {

throw new Error('mysql cannot make unique with nullsNotDistinct option');
}
indexName = indexName
? this.formatter.wrap(indexName)
: this._indexCommand('unique', this.tableNameRaw, columns);
Expand Down
6 changes: 5 additions & 1 deletion lib/dialects/oracle/schema/oracle-tablecompiler.js
Expand Up @@ -156,8 +156,12 @@ class TableCompiler_Oracle extends TableCompiler {

unique(columns, indexName) {
let deferrable;
let nullsNotDistinct;
if (isObject(indexName)) {
({ indexName, deferrable } = indexName);
({ indexName, deferrable, nullsNotDistinct } = indexName);
}
if (nullsNotDistinct !== undefined) {
Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

allow null as well

Suggested change
if (nullsNotDistinct !== undefined) {
if (nullsNotDistinct != null) {

throw new Error('oracle cannot make unique with nullsNotDistinct option');
}
deferrable = deferrable ? ` deferrable initially ${deferrable}` : '';
indexName = indexName
Expand Down
14 changes: 12 additions & 2 deletions lib/dialects/postgres/schema/pg-tablecompiler.js
Expand Up @@ -191,8 +191,10 @@ class TableCompiler_PG extends TableCompiler {
let deferrable;
let useConstraint = true;
let predicate;
let nullsNotDistinct;
if (isObject(indexName)) {
({ indexName, deferrable, useConstraint, predicate } = indexName);
({ indexName, deferrable, useConstraint, predicate, nullsNotDistinct } =
indexName);
if (useConstraint === undefined) {
useConstraint = !!deferrable || !predicate;
}
Expand All @@ -204,6 +206,13 @@ class TableCompiler_PG extends TableCompiler {
throw new Error('postgres cannot create constraint with predicate');
}
deferrable = deferrable ? ` deferrable initially ${deferrable}` : '';
if (nullsNotDistinct !== undefined) {
nullsNotDistinct = nullsNotDistinct
? ' nulls not distinct'
: ' nulls distinct';
} else {
nullsNotDistinct = '';
}
indexName = indexName
? this.formatter.wrap(indexName)
: this._indexCommand('unique', this.tableNameRaw, columns);
Expand All @@ -214,6 +223,7 @@ class TableCompiler_PG extends TableCompiler {
' unique (' +
this.formatter.columnize(columns) +
')' +
nullsNotDistinct +
deferrable
);
} else {
Expand All @@ -224,7 +234,7 @@ class TableCompiler_PG extends TableCompiler {
this.pushQuery(
`create unique index ${indexName} on ${this.tableName()} (${this.formatter.columnize(
columns
)})${predicateQuery}`
)})${nullsNotDistinct}${predicateQuery}`
);
}
}
Expand Down
8 changes: 7 additions & 1 deletion lib/dialects/sqlite3/schema/sqlite-tablecompiler.js
Expand Up @@ -133,8 +133,14 @@ class TableCompiler_SQLite3 extends TableCompiler {
unique(columns, indexName) {
let deferrable;
let predicate;
let nullsNotDistinct;
if (isObject(indexName)) {
({ indexName, deferrable, predicate } = indexName);
({ indexName, deferrable, predicate, nullsNotDistinct } = indexName);
}
if (nullsNotDistinct !== undefined) {
Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

allow null as well

Suggested change
if (nullsNotDistinct !== undefined) {
if (nullsNotDistinct != null) {

throw new Error(
'sqlite3 cannot make unique with nullsNotDistinct option'
);
}
if (deferrable && deferrable !== 'not deferrable') {
this.client.logger.warn(
Expand Down
64 changes: 64 additions & 0 deletions test/unit/schema-builder/postgres.js
Expand Up @@ -740,6 +740,36 @@ describe('PostgreSQL SchemaBuilder', function () {
);
});

it('adds unique constraint with nulls not distinct', function () {
tableSql = client
.schemaBuilder()
.createTable('person', function (table) {
table
.integer('user_id')
.unique({ indexName: 'user_id_index', nullsNotDistinct: true });
})
.toSQL();
equal(2, tableSql.length);
expect(tableSql[1].sql).to.equal(
'alter table "person" add constraint "user_id_index" unique ("user_id") nulls not distinct'
);
});

it('adds unique constraint with nulls distinct', function () {
tableSql = client
.schemaBuilder()
.createTable('person', function (table) {
table
.integer('user_id')
.unique({ indexName: 'user_id_index', nullsNotDistinct: false });
})
.toSQL();
equal(2, tableSql.length);
expect(tableSql[1].sql).to.equal(
'alter table "person" add constraint "user_id_index" unique ("user_id") nulls distinct'
);
});

it('adds primary constraint with deferrable initially immediate', function () {
tableSql = client
.schemaBuilder()
Expand Down Expand Up @@ -1079,6 +1109,40 @@ describe('PostgreSQL SchemaBuilder', function () {
);
});

it('adding unique index with nulls not distinct', function () {
tableSql = client
.schemaBuilder()
.table('users', function (table) {
table.unique('foo', {
indexName: 'bar',
useConstraint: false,
nullsNotDistinct: true,
});
})
.toSQL();
equal(1, tableSql.length);
expect(tableSql[0].sql).to.equal(
'create unique index "bar" on "users" ("foo") nulls not distinct'
);
});

it('adding unique index with nulls distinct', function () {
tableSql = client
.schemaBuilder()
.table('users', function (table) {
table.unique('foo', {
indexName: 'bar',
useConstraint: false,
nullsNotDistinct: false,
});
})
.toSQL();
equal(1, tableSql.length);
expect(tableSql[0].sql).to.equal(
'create unique index "bar" on "users" ("foo") nulls distinct'
);
});

it('adding unique index with a predicate', function () {
tableSql = client
.schemaBuilder()
Expand Down
1 change: 1 addition & 0 deletions types/index.d.ts
Expand Up @@ -2543,6 +2543,7 @@ declare namespace Knex {
deferrable?: deferrableType;
useConstraint?: boolean;
predicate?: QueryBuilder;
nullsNotDistinct?: boolean;
}>
): TableBuilder;
/** @deprecated */
Expand Down