mirror of
https://github.com/knex/knex.git
synced 2026-01-05 19:47:55 +00:00
feat: support partial unique indexes (#5316)
This commit is contained in:
parent
6bed5e99dd
commit
864530cd67
@ -280,20 +280,24 @@ class TableCompiler_MSSQL extends TableCompiler {
|
||||
* Create a unique index.
|
||||
*
|
||||
* @param {string | string[]} columns
|
||||
* @param {string | {indexName: undefined | string, deferrable?: 'not deferrable'|'deferred'|'immediate', useConstraint?: true|false }} indexName
|
||||
* @param {string | {indexName: undefined | string, deferrable?: 'not deferrable'|'deferred'|'immediate', useConstraint?: true|false, predicate?: QueryBuilder }} indexName
|
||||
*/
|
||||
unique(columns, indexName) {
|
||||
/** @type {string | undefined} */
|
||||
let deferrable;
|
||||
let useConstraint = false;
|
||||
let predicate;
|
||||
if (isObject(indexName)) {
|
||||
({ indexName, deferrable, useConstraint } = indexName);
|
||||
({ indexName, deferrable, useConstraint, predicate } = indexName);
|
||||
}
|
||||
if (deferrable && deferrable !== 'not deferrable') {
|
||||
this.client.logger.warn(
|
||||
`mssql: unique index [${indexName}] will not be deferrable ${deferrable} because mssql does not support deferred constraints.`
|
||||
);
|
||||
}
|
||||
if (useConstraint && predicate) {
|
||||
throw new Error('mssql cannot create constraint with predicate');
|
||||
}
|
||||
indexName = indexName
|
||||
? this.formatter.wrap(indexName)
|
||||
: this._indexCommand('unique', this.tableNameRaw, columns);
|
||||
@ -302,10 +306,6 @@ class TableCompiler_MSSQL extends TableCompiler {
|
||||
columns = [columns];
|
||||
}
|
||||
|
||||
const whereAllTheColumnsAreNotNull = columns
|
||||
.map((column) => this.formatter.columnize(column) + ' IS NOT NULL')
|
||||
.join(' AND ');
|
||||
|
||||
if (useConstraint) {
|
||||
// mssql supports unique indexes and unique constraints.
|
||||
// unique indexes cannot be used with foreign key relationships hence unique constraints are used instead.
|
||||
@ -315,12 +315,18 @@ class TableCompiler_MSSQL extends TableCompiler {
|
||||
)})`
|
||||
);
|
||||
} else {
|
||||
// make unique constraint that allows null https://stackoverflow.com/a/767702/360060
|
||||
// default to making unique index that allows null https://stackoverflow.com/a/767702/360060
|
||||
// to be more or less compatible with other DBs (if any of the columns is NULL then "duplicates" are allowed)
|
||||
const predicateQuery = predicate
|
||||
? ' ' + this.client.queryCompiler(predicate).where()
|
||||
: ' WHERE ' +
|
||||
columns
|
||||
.map((column) => this.formatter.columnize(column) + ' IS NOT NULL')
|
||||
.join(' AND ');
|
||||
this.pushQuery(
|
||||
`CREATE UNIQUE INDEX ${indexName} ON ${this.tableName()} (${this.formatter.columnize(
|
||||
columns
|
||||
)}) WHERE ${whereAllTheColumnsAreNotNull}`
|
||||
)})${predicateQuery}`
|
||||
);
|
||||
}
|
||||
}
|
||||
|
||||
@ -189,20 +189,44 @@ class TableCompiler_PG extends TableCompiler {
|
||||
|
||||
unique(columns, indexName) {
|
||||
let deferrable;
|
||||
let useConstraint = true;
|
||||
let predicate;
|
||||
if (isObject(indexName)) {
|
||||
({ indexName, deferrable } = indexName);
|
||||
({ indexName, deferrable, useConstraint, predicate } = indexName);
|
||||
if (useConstraint === undefined) {
|
||||
useConstraint = !!deferrable || !predicate;
|
||||
}
|
||||
}
|
||||
if (!useConstraint && deferrable && deferrable !== 'not deferrable') {
|
||||
throw new Error('postgres cannot create deferrable index');
|
||||
}
|
||||
if (useConstraint && predicate) {
|
||||
throw new Error('postgres cannot create constraint with predicate');
|
||||
}
|
||||
deferrable = deferrable ? ` deferrable initially ${deferrable}` : '';
|
||||
indexName = indexName
|
||||
? this.formatter.wrap(indexName)
|
||||
: this._indexCommand('unique', this.tableNameRaw, columns);
|
||||
this.pushQuery(
|
||||
`alter table ${this.tableName()} add constraint ${indexName}` +
|
||||
' unique (' +
|
||||
this.formatter.columnize(columns) +
|
||||
')' +
|
||||
deferrable
|
||||
);
|
||||
|
||||
if (useConstraint) {
|
||||
this.pushQuery(
|
||||
`alter table ${this.tableName()} add constraint ${indexName}` +
|
||||
' unique (' +
|
||||
this.formatter.columnize(columns) +
|
||||
')' +
|
||||
deferrable
|
||||
);
|
||||
} else {
|
||||
const predicateQuery = predicate
|
||||
? ' ' + this.client.queryCompiler(predicate).where()
|
||||
: '';
|
||||
|
||||
this.pushQuery(
|
||||
`create unique index ${indexName} on ${this.tableName()} (${this.formatter.columnize(
|
||||
columns
|
||||
)})${predicateQuery}`
|
||||
);
|
||||
}
|
||||
}
|
||||
|
||||
index(columns, indexName, options) {
|
||||
|
||||
@ -132,8 +132,9 @@ class TableCompiler_SQLite3 extends TableCompiler {
|
||||
// Compile a unique key command.
|
||||
unique(columns, indexName) {
|
||||
let deferrable;
|
||||
let predicate;
|
||||
if (isObject(indexName)) {
|
||||
({ indexName, deferrable } = indexName);
|
||||
({ indexName, deferrable, predicate } = indexName);
|
||||
}
|
||||
if (deferrable && deferrable !== 'not deferrable') {
|
||||
this.client.logger.warn(
|
||||
@ -144,8 +145,13 @@ class TableCompiler_SQLite3 extends TableCompiler {
|
||||
? this.formatter.wrap(indexName)
|
||||
: this._indexCommand('unique', this.tableNameRaw, columns);
|
||||
columns = this.formatter.columnize(columns);
|
||||
|
||||
const predicateQuery = predicate
|
||||
? ' ' + this.client.queryCompiler(predicate).where()
|
||||
: '';
|
||||
|
||||
this.pushQuery(
|
||||
`create unique index ${indexName} on ${this.tableName()} (${columns})`
|
||||
`create unique index ${indexName} on ${this.tableName()} (${columns})${predicateQuery}`
|
||||
);
|
||||
}
|
||||
|
||||
|
||||
@ -1659,6 +1659,43 @@ describe('Schema (misc)', () => {
|
||||
expect(results).to.not.be.empty;
|
||||
});
|
||||
});
|
||||
|
||||
describe('supports partial unique indexes - postgres, sqlite, and mssql', function () {
|
||||
it('allows creating a unique index with predicate', async function () {
|
||||
if (!(isPostgreSQL(knex) || isMssql(knex) || isSQLite(knex))) {
|
||||
return this.skip();
|
||||
}
|
||||
|
||||
await knex.schema.table('test_table_one', function (t) {
|
||||
t.unique('email', {
|
||||
indexName: 'email_idx',
|
||||
predicate: knex.whereNotNull('email'),
|
||||
});
|
||||
});
|
||||
});
|
||||
|
||||
it('actually stores the predicate in the Postgres server', async function () {
|
||||
if (!isPostgreSQL(knex)) {
|
||||
return this.skip();
|
||||
}
|
||||
await knex.schema.table('test_table_one', function (t) {
|
||||
t.unique('email', {
|
||||
indexName: 'email_idx_2',
|
||||
predicate: knex.whereNotNull('email'),
|
||||
});
|
||||
});
|
||||
const results = await knex
|
||||
.from('pg_class')
|
||||
.innerJoin('pg_index', 'pg_index.indexrelid', 'pg_class.oid')
|
||||
.where({
|
||||
relname: 'email_idx_2',
|
||||
indisvalid: true,
|
||||
indisunique: true,
|
||||
})
|
||||
.whereNotNull('indpred');
|
||||
expect(results).to.not.be.empty;
|
||||
});
|
||||
});
|
||||
});
|
||||
|
||||
describe('hasTable', () => {
|
||||
|
||||
@ -641,6 +641,53 @@ describe('MSSQL SchemaBuilder', function () {
|
||||
);
|
||||
});
|
||||
|
||||
it('test adding unique index with a predicate', function () {
|
||||
tableSql = client
|
||||
.schemaBuilder()
|
||||
.table('users', function (table) {
|
||||
table.unique(['foo', 'bar'], {
|
||||
indexName: 'baz',
|
||||
predicate: client.queryBuilder().whereRaw('email = "foo@bar"'),
|
||||
});
|
||||
})
|
||||
.toSQL();
|
||||
equal(1, tableSql.length);
|
||||
expect(tableSql[0].sql).to.equal(
|
||||
'CREATE UNIQUE INDEX [baz] ON [users] ([foo], [bar]) where email = "foo@bar"'
|
||||
);
|
||||
});
|
||||
|
||||
it('test adding unique index with a where not null predicate', function () {
|
||||
tableSql = client
|
||||
.schemaBuilder()
|
||||
.table('users', function (table) {
|
||||
table.unique(['foo', 'bar'], {
|
||||
indexName: 'baz',
|
||||
predicate: client.queryBuilder().whereNotNull('email'),
|
||||
});
|
||||
})
|
||||
.toSQL();
|
||||
equal(1, tableSql.length);
|
||||
expect(tableSql[0].sql).to.equal(
|
||||
'CREATE UNIQUE INDEX [baz] ON [users] ([foo], [bar]) where [email] is not null'
|
||||
);
|
||||
});
|
||||
|
||||
it('throws when adding unique constraint with predicate', function () {
|
||||
expect(() => {
|
||||
client
|
||||
.schemaBuilder()
|
||||
.table('users', function (table) {
|
||||
table.unique(['foo', 'bar'], {
|
||||
indexName: 'baz',
|
||||
useConstraint: true,
|
||||
predicate: client.queryBuilder().whereRaw('email = "foo@bar"'),
|
||||
});
|
||||
})
|
||||
.toSQL();
|
||||
}).to.throw('mssql cannot create constraint with predicate');
|
||||
});
|
||||
|
||||
it('test adding foreign key', function () {
|
||||
tableSql = client
|
||||
.schemaBuilder()
|
||||
|
||||
@ -915,6 +915,22 @@ describe('PostgreSQL SchemaBuilder', function () {
|
||||
);
|
||||
});
|
||||
|
||||
it('adding unique index', function () {
|
||||
tableSql = client
|
||||
.schemaBuilder()
|
||||
.table('users', function (table) {
|
||||
table.unique('foo', {
|
||||
indexName: 'bar',
|
||||
useConstraint: false,
|
||||
});
|
||||
})
|
||||
.toSQL();
|
||||
equal(1, tableSql.length);
|
||||
expect(tableSql[0].sql).to.equal(
|
||||
'create unique index "bar" on "users" ("foo")'
|
||||
);
|
||||
});
|
||||
|
||||
it('adding index without value', function () {
|
||||
tableSql = client
|
||||
.schemaBuilder()
|
||||
@ -1048,6 +1064,68 @@ describe('PostgreSQL SchemaBuilder', function () {
|
||||
);
|
||||
});
|
||||
|
||||
it('adding unique index with a predicate', function () {
|
||||
tableSql = client
|
||||
.schemaBuilder()
|
||||
.table('users', function (table) {
|
||||
table.unique(['foo', 'bar'], {
|
||||
indexName: 'baz',
|
||||
predicate: client.queryBuilder().whereRaw('email = "foo@bar"'),
|
||||
});
|
||||
})
|
||||
.toSQL();
|
||||
equal(1, tableSql.length);
|
||||
expect(tableSql[0].sql).to.equal(
|
||||
'create unique index "baz" on "users" ("foo", "bar") where email = "foo@bar"'
|
||||
);
|
||||
});
|
||||
|
||||
it('adding unique index with a where not null predicate', function () {
|
||||
tableSql = client
|
||||
.schemaBuilder()
|
||||
.table('users', function (table) {
|
||||
table.unique(['foo', 'bar'], {
|
||||
indexName: 'baz',
|
||||
predicate: client.queryBuilder().whereNotNull('email'),
|
||||
});
|
||||
})
|
||||
.toSQL();
|
||||
equal(1, tableSql.length);
|
||||
expect(tableSql[0].sql).to.equal(
|
||||
'create unique index "baz" on "users" ("foo", "bar") where "email" is not null'
|
||||
);
|
||||
});
|
||||
|
||||
it('throws when adding unique constraint with a predicate', function () {
|
||||
expect(() => {
|
||||
client
|
||||
.schemaBuilder()
|
||||
.table('users', function (table) {
|
||||
table.unique(['foo', 'bar'], {
|
||||
indexName: 'baz',
|
||||
useConstraint: true,
|
||||
predicate: client.queryBuilder().whereNotNull('email'),
|
||||
});
|
||||
})
|
||||
.toSQL();
|
||||
}).to.throw('postgres cannot create constraint with predicate');
|
||||
});
|
||||
|
||||
it('throws when adding unique index with deferrable set', function () {
|
||||
expect(() => {
|
||||
client
|
||||
.schemaBuilder()
|
||||
.table('users', function (table) {
|
||||
table.unique(['foo', 'bar'], {
|
||||
indexName: 'baz',
|
||||
useConstraint: false,
|
||||
deferrable: 'immediate',
|
||||
});
|
||||
})
|
||||
.toSQL();
|
||||
}).to.throw('postgres cannot create deferrable index');
|
||||
});
|
||||
|
||||
it('adding incrementing id', function () {
|
||||
tableSql = client
|
||||
.schemaBuilder()
|
||||
|
||||
@ -547,6 +547,38 @@ describe('SQLite SchemaBuilder', function () {
|
||||
);
|
||||
});
|
||||
|
||||
it('adding unique index with a predicate', function () {
|
||||
tableSql = client
|
||||
.schemaBuilder()
|
||||
.table('users', function (table) {
|
||||
table.unique(['foo', 'bar'], {
|
||||
indexName: 'baz',
|
||||
predicate: client.queryBuilder().whereRaw('email = "foo@bar"'),
|
||||
});
|
||||
})
|
||||
.toSQL();
|
||||
equal(1, tableSql.length);
|
||||
expect(tableSql[0].sql).to.equal(
|
||||
'create unique index `baz` on `users` (`foo`, `bar`) where email = "foo@bar"'
|
||||
);
|
||||
});
|
||||
|
||||
it('adding unique index with a where not null predicate', function () {
|
||||
tableSql = client
|
||||
.schemaBuilder()
|
||||
.table('users', function (table) {
|
||||
table.unique(['foo', 'bar'], {
|
||||
indexName: 'baz',
|
||||
predicate: client.queryBuilder().whereNotNull('email'),
|
||||
});
|
||||
})
|
||||
.toSQL();
|
||||
equal(1, tableSql.length);
|
||||
expect(tableSql[0].sql).to.equal(
|
||||
'create unique index `baz` on `users` (`foo`, `bar`) where `email` is not null'
|
||||
);
|
||||
});
|
||||
|
||||
it('adding incrementing id', function () {
|
||||
tableSql = client
|
||||
.schemaBuilder()
|
||||
|
||||
1
types/index.d.ts
vendored
1
types/index.d.ts
vendored
@ -2513,6 +2513,7 @@ export declare namespace Knex {
|
||||
storageEngineIndexType?: string;
|
||||
deferrable?: deferrableType;
|
||||
useConstraint?: boolean;
|
||||
predicate?: QueryBuilder;
|
||||
}>
|
||||
): TableBuilder;
|
||||
/** @deprecated */
|
||||
|
||||
Loading…
x
Reference in New Issue
Block a user