From d7c2e2df2c0e51a2b82f751a926291e3ec1ce1d5 Mon Sep 17 00:00:00 2001 From: abalabahaha Date: Wed, 31 Aug 2022 03:04:02 +0000 Subject: [PATCH 1/2] feat: support partial unique indexes --- .../mssql/schema/mssql-tablecompiler.js | 22 +++-- .../postgres/schema/pg-tablecompiler.js | 40 ++++++-- .../sqlite3/schema/sqlite-tablecompiler.js | 10 +- test/integration2/schema/misc.spec.js | 37 ++++++++ test/unit/schema-builder/mssql.js | 47 +++++++++ test/unit/schema-builder/postgres.js | 95 +++++++++++++++++++ test/unit/schema-builder/sqlite3.js | 32 +++++++ types/index.d.ts | 1 + 8 files changed, 266 insertions(+), 18 deletions(-) diff --git a/lib/dialects/mssql/schema/mssql-tablecompiler.js b/lib/dialects/mssql/schema/mssql-tablecompiler.js index a4d0959496..4802bd71bd 100644 --- a/lib/dialects/mssql/schema/mssql-tablecompiler.js +++ b/lib/dialects/mssql/schema/mssql-tablecompiler.js @@ -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}` ); } } diff --git a/lib/dialects/postgres/schema/pg-tablecompiler.js b/lib/dialects/postgres/schema/pg-tablecompiler.js index d2eeb9803a..dd029cf1a0 100644 --- a/lib/dialects/postgres/schema/pg-tablecompiler.js +++ b/lib/dialects/postgres/schema/pg-tablecompiler.js @@ -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) { diff --git a/lib/dialects/sqlite3/schema/sqlite-tablecompiler.js b/lib/dialects/sqlite3/schema/sqlite-tablecompiler.js index 930693f182..76c6453102 100644 --- a/lib/dialects/sqlite3/schema/sqlite-tablecompiler.js +++ b/lib/dialects/sqlite3/schema/sqlite-tablecompiler.js @@ -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}` ); } diff --git a/test/integration2/schema/misc.spec.js b/test/integration2/schema/misc.spec.js index 20db0132a9..befed615db 100644 --- a/test/integration2/schema/misc.spec.js +++ b/test/integration2/schema/misc.spec.js @@ -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', () => { diff --git a/test/unit/schema-builder/mssql.js b/test/unit/schema-builder/mssql.js index d33200f94d..eeef5a099e 100644 --- a/test/unit/schema-builder/mssql.js +++ b/test/unit/schema-builder/mssql.js @@ -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() diff --git a/test/unit/schema-builder/postgres.js b/test/unit/schema-builder/postgres.js index a77f68c7ae..3acffcdbb0 100644 --- a/test/unit/schema-builder/postgres.js +++ b/test/unit/schema-builder/postgres.js @@ -880,6 +880,22 @@ describe('PostgreSQL SchemaBuilder', function () { ); }); + it('adding unique index', function () { + tableSql = client + .schemaBuilder() + .table('users', function (table) { + table.unique('foo', { + indexName: 'bar', + useConstraint: true, + }); + }) + .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() @@ -1013,6 +1029,85 @@ 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 an index type and a predicate', function () { + tableSql = client + .schemaBuilder() + .table('users', function (table) { + table.unique(['foo', 'bar'], { + indexName: 'baz', + indexType: 'gist', + predicate: client.queryBuilder().whereRaw('email = "foo@bar"'), + }); + }) + .toSQL(); + equal(1, tableSql.length); + expect(tableSql[0].sql).to.equal( + 'create unique index "baz" on "users" using gist ("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() diff --git a/test/unit/schema-builder/sqlite3.js b/test/unit/schema-builder/sqlite3.js index 164b52e4ff..fa5742cb4b 100644 --- a/test/unit/schema-builder/sqlite3.js +++ b/test/unit/schema-builder/sqlite3.js @@ -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() diff --git a/types/index.d.ts b/types/index.d.ts index 69dc3c8df4..25317c3d99 100644 --- a/types/index.d.ts +++ b/types/index.d.ts @@ -2513,6 +2513,7 @@ export declare namespace Knex { storageEngineIndexType?: string; deferrable?: deferrableType; useConstraint?: boolean; + predicate?: QueryBuilder; }> ): TableBuilder; /** @deprecated */ From 60da980f3166766337a0a6cbc62cb5e1bed6dd54 Mon Sep 17 00:00:00 2001 From: abalabahaha Date: Thu, 1 Sep 2022 00:54:02 +0000 Subject: [PATCH 2/2] fix incorrect tests --- test/unit/schema-builder/postgres.js | 19 +------------------ 1 file changed, 1 insertion(+), 18 deletions(-) diff --git a/test/unit/schema-builder/postgres.js b/test/unit/schema-builder/postgres.js index 3acffcdbb0..4bf909f3bf 100644 --- a/test/unit/schema-builder/postgres.js +++ b/test/unit/schema-builder/postgres.js @@ -886,7 +886,7 @@ describe('PostgreSQL SchemaBuilder', function () { .table('users', function (table) { table.unique('foo', { indexName: 'bar', - useConstraint: true, + useConstraint: false, }); }) .toSQL(); @@ -1045,23 +1045,6 @@ describe('PostgreSQL SchemaBuilder', function () { ); }); - it('adding unique index with an index type and a predicate', function () { - tableSql = client - .schemaBuilder() - .table('users', function (table) { - table.unique(['foo', 'bar'], { - indexName: 'baz', - indexType: 'gist', - predicate: client.queryBuilder().whereRaw('email = "foo@bar"'), - }); - }) - .toSQL(); - equal(1, tableSql.length); - expect(tableSql[0].sql).to.equal( - 'create unique index "baz" on "users" using gist ("foo", "bar") where email = "foo@bar"' - ); - }); - it('adding unique index with a where not null predicate', function () { tableSql = client .schemaBuilder()