Checks Constraints Support (#4874)

Co-authored-by: Ivan Zhuravlev <intech@users.noreply.github.com>
This commit is contained in:
Olivier Cavadenti 2022-01-06 14:44:16 +01:00 committed by GitHub
parent b6775d9b00
commit 4494113187
No known key found for this signature in database
GPG Key ID: 4AEE18F83AFDEB23
25 changed files with 1559 additions and 50 deletions

View File

@ -7,6 +7,25 @@ class TableCompiler_CRDB extends TableCompiler {
super(client, tableBuilder);
}
addColumns(columns, prefix, colCompilers) {
if (prefix === this.alterColumnsPrefix) {
// alter columns
for (const col of colCompilers) {
this.client.logger.warn(
'Experimental alter column in use, see issue: https://github.com/cockroachdb/cockroach/issues/49329'
);
this.pushQuery({
sql: 'SET enable_experimental_alter_column_type_general = true',
bindings: [],
});
super._addColumn(col);
}
} else {
// base class implementation for normal add
super.addColumns(columns, prefix);
}
}
dropUnique(columns, indexName) {
indexName = indexName
? this.formatter.wrap(indexName)

View File

@ -3,11 +3,13 @@
const ColumnCompiler = require('../../../schema/columncompiler');
const { toNumber } = require('../../../util/helpers');
const { formatDefault } = require('../../../formatter/formatterUtils');
const { operator: operator_ } = require('../../../formatter/wrappingFormatter');
class ColumnCompiler_MSSQL extends ColumnCompiler {
constructor(client, tableCompiler, columnBuilder) {
super(client, tableCompiler, columnBuilder);
this.modifiers = ['nullable', 'defaultTo', 'first', 'after', 'comment'];
this._addCheckModifiers();
}
// Types
@ -127,6 +129,26 @@ class ColumnCompiler_MSSQL extends ColumnCompiler {
return '';
}
checkLength(operator, length, constraintName) {
return this._check(
`LEN(${this.formatter.wrap(this.getColumnName())}) ${operator_(
operator,
this.columnBuilder,
this.bindingsHolder
)} ${toNumber(length)}`,
constraintName
);
}
checkRegex(regex, constraintName) {
return this._check(
`${this.formatter.wrap(
this.getColumnName()
)} LIKE ${this.client._escapeBinding('%' + regex + '%')}`,
constraintName
);
}
increments(options = { primaryKey: true }) {
return (
'int identity(1,1) not null' +

View File

@ -28,6 +28,7 @@ class TableCompiler_MSSQL extends TableCompiler {
this.tableName() +
(this._formatting ? ' (\n ' : ' (') +
columns.sql.join(this._formatting ? ',\n ' : ', ') +
this._addChecks() +
')';
}

View File

@ -18,6 +18,7 @@ class ColumnCompiler_MySQL extends ColumnCompiler {
'first',
'after',
];
this._addCheckModifiers();
}
// Types
@ -153,6 +154,15 @@ class ColumnCompiler_MySQL extends ColumnCompiler {
return collation && `collate '${collation}'`;
}
checkRegex(regex, constraintName) {
return this._check(
`${this.formatter.wrap(
this.getColumnName()
)} REGEXP ${this.client._escapeBinding(regex)}`,
constraintName
);
}
increments(options = { primaryKey: true }) {
return (
'int unsigned not null' +

View File

@ -19,7 +19,7 @@ class TableCompiler_MySQL extends TableCompiler {
: 'create table ';
const { client } = this;
let conn = {};
const columnsSql = ' (' + columns.sql.join(', ') + ')';
const columnsSql = ' (' + columns.sql.join(', ') + this._addChecks() + ')';
let sql =
createStatement +
this.tableName() +

View File

@ -57,7 +57,7 @@ class TableCompiler_Oracle extends TableCompiler {
const columnsSql =
like && this.tableNameLike()
? ' as (select * from ' + this.tableNameLike() + ' where 0=1)'
: ' (' + columns.sql.join(', ') + ')';
: ' (' + columns.sql.join(', ') + this._addChecks() + ')';
const sql = `create table ${this.tableName()}${columnsSql}`;
this.pushQuery({

View File

@ -4,6 +4,8 @@ const { isObject } = require('../../../util/is');
class ColumnCompiler_Oracledb extends ColumnCompiler_Oracle {
constructor() {
super(...arguments);
this.modifiers = ['defaultTo', 'nullable', 'comment'];
this._addCheckModifiers();
}
datetime(withoutTz) {
@ -26,6 +28,15 @@ class ColumnCompiler_Oracledb extends ColumnCompiler_Oracle {
return useTz ? 'timestamp with local time zone' : 'timestamp';
}
checkRegex(regex, constraintName) {
return this._check(
`REGEXP_LIKE(${this.formatter.wrap(
this.getColumnName()
)},${this.client._escapeBinding(regex)})`,
constraintName
);
}
json() {
return `varchar2(4000) check (${this.formatter.columnize(
this.getColumnName()

View File

@ -10,6 +10,7 @@ class ColumnCompiler_PG extends ColumnCompiler {
constructor(client, tableCompiler, columnBuilder) {
super(client, tableCompiler, columnBuilder);
this.modifiers = ['nullable', 'defaultTo', 'comment'];
this._addCheckModifiers();
}
// Types
@ -64,6 +65,15 @@ class ColumnCompiler_PG extends ColumnCompiler {
return jsonColumn(this.client, true);
}
checkRegex(regex, constraintName) {
return this._check(
`${this.formatter.wrap(
this.getColumnName()
)} ~ ${this.client._escapeBinding(regex)}`,
constraintName
);
}
datetime(withoutTz = false, precision) {
let useTz;
if (isObject(withoutTz)) {

View File

@ -44,7 +44,7 @@ class TableCompiler_PG extends TableCompiler {
const createStatement = ifNot
? 'create table if not exists '
: 'create table ';
const columnsSql = ' (' + columns.sql.join(', ') + ')';
const columnsSql = ' (' + columns.sql.join(', ') + this._addChecks() + ')';
let sql =
createStatement +
this.tableName() +
@ -69,51 +69,7 @@ class TableCompiler_PG extends TableCompiler {
if (prefix === this.alterColumnsPrefix) {
// alter columns
for (const col of colCompilers) {
const quotedTableName = this.tableName();
const type = col.getColumnType();
// We'd prefer to call this.formatter.wrapAsIdentifier here instead, however the context passed to
// `this` instance is not that of the column, but of the table. Thus, we unfortunately have to call
// `wrapIdentifier` here as well (it is already called once on the initial column operation) to give
// our `alter` operation the correct `queryContext`. Refer to issue #2606 and PR #2612.
const colName = this.client.wrapIdentifier(
col.getColumnName(),
col.columnBuilder.queryContext()
);
// To alter enum columns they must be cast to text first
const isEnum = col.type === 'enu';
this.pushQuery({
sql: `alter table ${quotedTableName} alter column ${colName} drop default`,
bindings: [],
});
this.pushQuery({
sql: `alter table ${quotedTableName} alter column ${colName} drop not null`,
bindings: [],
});
this.pushQuery({
sql: `alter table ${quotedTableName} alter column ${colName} type ${type} using (${colName}${
isEnum ? '::text::' : '::'
}${type})`,
bindings: [],
});
const defaultTo = col.modified['defaultTo'];
if (defaultTo) {
const modifier = col.defaultTo.apply(col, defaultTo);
this.pushQuery({
sql: `alter table ${quotedTableName} alter column ${colName} set ${modifier}`,
bindings: [],
});
}
const nullable = col.modified['nullable'];
if (nullable && nullable[0] === false) {
this.pushQuery({
sql: `alter table ${quotedTableName} alter column ${colName} set not null`,
bindings: [],
});
}
this._addColumn(col);
}
} else {
// base class implementation for normal add
@ -121,6 +77,54 @@ class TableCompiler_PG extends TableCompiler {
}
}
_addColumn(col) {
const quotedTableName = this.tableName();
const type = col.getColumnType();
// We'd prefer to call this.formatter.wrapAsIdentifier here instead, however the context passed to
// `this` instance is not that of the column, but of the table. Thus, we unfortunately have to call
// `wrapIdentifier` here as well (it is already called once on the initial column operation) to give
// our `alter` operation the correct `queryContext`. Refer to issue #2606 and PR #2612.
const colName = this.client.wrapIdentifier(
col.getColumnName(),
col.columnBuilder.queryContext()
);
// To alter enum columns they must be cast to text first
const isEnum = col.type === 'enu';
this.pushQuery({
sql: `alter table ${quotedTableName} alter column ${colName} drop default`,
bindings: [],
});
this.pushQuery({
sql: `alter table ${quotedTableName} alter column ${colName} drop not null`,
bindings: [],
});
this.pushQuery({
sql: `alter table ${quotedTableName} alter column ${colName} type ${type} using (${colName}${
isEnum ? '::text::' : '::'
}${type})`,
bindings: [],
});
const defaultTo = col.modified['defaultTo'];
if (defaultTo) {
const modifier = col.defaultTo.apply(col, defaultTo);
this.pushQuery({
sql: `alter table ${quotedTableName} alter column ${colName} set ${modifier}`,
bindings: [],
});
}
const nullable = col.modified['nullable'];
if (nullable && nullable[0] === false) {
this.pushQuery({
sql: `alter table ${quotedTableName} alter column ${colName} set not null`,
bindings: [],
});
}
}
// Compiles the comment on the table.
comment(comment) {
this.pushQuery(

View File

@ -30,7 +30,7 @@ class TableCompiler_Redshift extends TableCompiler_PG {
const createStatement = ifNot
? 'create table if not exists '
: 'create table ';
const columnsSql = ' (' + columns.sql.join(', ') + ')';
const columnsSql = ' (' + columns.sql.join(', ') + this._addChecks() + ')';
let sql =
createStatement +
this.tableName() +

View File

@ -7,6 +7,7 @@ class ColumnCompiler_SQLite3 extends ColumnCompiler {
constructor() {
super(...arguments);
this.modifiers = ['nullable', 'defaultTo'];
this._addCheckModifiers();
}
// Types
@ -17,6 +18,21 @@ class ColumnCompiler_SQLite3 extends ColumnCompiler {
this.args[0]
)} in ('${allowed.join("', '")}'))`;
}
_pushAlterCheckQuery(checkPredicate, constraintName) {
throw new Error(
`Alter table with to add constraints is not permitted in SQLite`
);
}
checkRegex(regexes, constraintName) {
return this._check(
`${this.formatter.wrap(
this.getColumnName()
)} REGEXP ${this.client._escapeBinding(regexes)}`,
constraintName
);
}
}
ColumnCompiler_SQLite3.prototype.json = 'json';

View File

@ -27,6 +27,7 @@ class TableCompiler_SQLite3 extends TableCompiler {
sql += ' (' + columns.sql.join(', ');
sql += this.foreignKeys() || '';
sql += this.primaryKeys() || '';
sql += this._addChecks();
sql += ')';
}
this.pushQuery(sql);

View File

@ -42,6 +42,14 @@ const modifiers = [
'after',
'comment',
'collate',
'check',
'checkPositive',
'checkNegative',
'checkIn',
'checkNotIn',
'checkBetween',
'checkLength',
'checkRegex',
];
// Aliases for convenience.

View File

@ -9,6 +9,7 @@ const has = require('lodash/has');
const tail = require('lodash/tail');
const { toNumber } = require('../util/helpers');
const { formatDefault } = require('../formatter/formatterUtils');
const { operator: operator_ } = require('../formatter/wrappingFormatter');
class ColumnCompiler {
constructor(client, tableCompiler, columnBuilder) {
@ -29,6 +30,21 @@ class ColumnCompiler {
this.sequence = [];
this.modifiers = [];
this.checksCount = 0;
}
_addCheckModifiers() {
this.modifiers.push(
'check',
'checkPositive',
'checkNegative',
'checkIn',
'checkNotIn',
'checkBetween',
'checkLength',
'checkRegex'
);
}
defaults(label) {
@ -146,6 +162,108 @@ class ColumnCompiler {
bigincrements(options = { primaryKey: true }) {
return this.increments(options);
}
_pushAlterCheckQuery(checkPredicate, constraintName) {
let checkName = constraintName;
if (!checkName) {
this.checksCount++;
checkName =
this.tableCompiler.tableNameRaw +
'_' +
this.getColumnName() +
'_' +
this.checksCount;
}
this.pushAdditional(function () {
this.pushQuery(
`alter table ${this.tableCompiler.tableName()} add constraint ${checkName} check(${checkPredicate})`
);
});
}
_checkConstraintName(constraintName) {
return constraintName ? `constraint ${constraintName} ` : '';
}
_check(checkPredicate, constraintName) {
if (this.columnBuilder._method === 'alter') {
this._pushAlterCheckQuery(checkPredicate, constraintName);
return '';
}
return `${this._checkConstraintName(
constraintName
)}check (${checkPredicate})`;
}
checkPositive(constraintName) {
return this._check(
`${this.formatter.wrap(this.getColumnName())} ${operator_(
'>',
this.columnBuilder,
this.bindingsHolder
)} 0`,
constraintName
);
}
checkNegative(constraintName) {
return this._check(
`${this.formatter.wrap(this.getColumnName())} ${operator_(
'<',
this.columnBuilder,
this.bindingsHolder
)} 0`,
constraintName
);
}
_checkIn(values, constraintName, not) {
return this._check(
`${this.formatter.wrap(this.getColumnName())} ${
not ? 'not ' : ''
}in (${values.map((v) => this.client._escapeBinding(v)).join(',')})`,
constraintName
);
}
checkIn(values, constraintName) {
return this._checkIn(values, constraintName);
}
checkNotIn(values, constraintName) {
return this._checkIn(values, constraintName, true);
}
checkBetween(intervals, constraintName) {
if (
intervals.length === 2 &&
!Array.isArray(intervals[0]) &&
!Array.isArray(intervals[1])
) {
intervals = [intervals];
}
const intervalChecks = intervals
.map((interval) => {
return `${this.formatter.wrap(
this.getColumnName()
)} between ${this.client._escapeBinding(
interval[0]
)} and ${this.client._escapeBinding(interval[1])}`;
})
.join(' or ');
return this._check(intervalChecks, constraintName);
}
checkLength(operator, length, constraintName) {
return this._check(
`length(${this.formatter.wrap(this.getColumnName())}) ${operator_(
operator,
this.columnBuilder,
this.bindingsHolder
)} ${toNumber(length)}`,
constraintName
);
}
}
ColumnCompiler.prototype.binary = 'blob';

View File

@ -146,6 +146,14 @@ class TableBuilder {
};
return returnObj;
}
check(checkPredicate, bindings, constraintName) {
this._statements.push({
grouping: 'checks',
args: [checkPredicate, bindings, constraintName],
});
return this;
}
}
[
@ -312,6 +320,22 @@ const AlterMethods = {
return this;
},
check(checkPredicate, bindings, constraintName) {
this._statements.push({
grouping: 'alterTable',
method: 'check',
args: [checkPredicate, bindings, constraintName],
});
},
dropChecks() {
this._statements.push({
grouping: 'alterTable',
method: 'dropChecks',
args: toArray(arguments),
});
},
dropNullable(column) {
this._statements.push({
grouping: 'alterTable',

View File

@ -12,6 +12,7 @@ const groupBy = require('lodash/groupBy');
const indexOf = require('lodash/indexOf');
const isEmpty = require('lodash/isEmpty');
const tail = require('lodash/tail');
const { normalizeArr } = require('../util/helpers');
class TableCompiler {
constructor(client, tableBuilder) {
@ -32,6 +33,8 @@ class TableCompiler {
this.sequence = [];
this._formatting = client.config && client.config.formatting;
this.checksCount = 0;
}
// Convert the tableCompiler toSQL
@ -346,6 +349,43 @@ class TableCompiler {
return this._setNullableState(column, false);
}
dropChecks(checkConstraintNames) {
if (checkConstraintNames === undefined) return '';
checkConstraintNames = normalizeArr(checkConstraintNames);
const tableName = this.tableName();
const sql = `alter table ${tableName} ${checkConstraintNames
.map((constraint) => `drop constraint ${constraint}`)
.join(', ')}`;
this.pushQuery(sql);
}
check(checkPredicate, bindings, constraintName) {
const tableName = this.tableName();
let checkConstraint = constraintName;
if (!checkConstraint) {
this.checksCount++;
checkConstraint = tableName + '_' + this.checksCount;
}
const sql = `alter table ${tableName} add constraint ${checkConstraint} check(${checkPredicate})`;
this.pushQuery(sql);
}
_addChecks() {
if (this.grouped.checks) {
return (
', ' +
this.grouped.checks
.map((c) => {
return `${
c.args[2] ? 'constraint ' + c.args[2] + ' ' : ''
}check (${this.client.raw(c.args[0], c.args[1])})`;
})
.join(', ')
);
}
return '';
}
// If no name was specified for this index, we will create one using a basic
// convention of the table name, followed by the columns, followed by an
// index type, such as primary or index, which makes the index unique.

View File

@ -85,7 +85,7 @@ services:
- 'until /usr/local/bin/psql postgres://testuser:knextest@postgres/knex_test -c "SELECT 1"; do sleep 5; done'
cockroachdb:
image: cockroachdb/cockroach:latest-v21.1
image: cockroachdb/cockroach:latest-v21.2
container_name: crdb
hostname: crdb
command: start-single-node --cluster-name=example-single-node --insecure

View File

@ -0,0 +1,450 @@
'use strict';
const { expect } = require('chai');
require('lodash');
const { isSQLite, isMssql } = require('../../util/db-helpers');
const { getAllDbs, getKnexForDb } = require('../util/knex-instance-provider');
const logger = require('../../integration/logger');
describe('Checks', () => {
getAllDbs().forEach((db) => {
describe(db, () => {
let knex;
before(async () => {
knex = logger(getKnexForDb(db));
});
after(async () => {
return knex.destroy();
});
/**
* Perform a check constraint with two tests : test the check constraint don't trigger on valid insert and
* test the constraint trigger on invalid insert.
*
* @param validInsert the valid insert object.
* @param invalidInsert the valid insert object.
* @returns {Promise<void>}
*/
async function checkTest(validInsert, invalidInsert) {
try {
await knex('check_test').insert([validInsert]);
} catch (err) {
expect(
err,
`valid insert ${JSON.stringify(
validInsert
)} thrown error (${err.toString()}) instead of pass`
).to.undefined;
}
let res;
try {
res = await knex('check_test').insert([invalidInsert]);
} catch (err) {
expect(err).to.not.undefined;
}
expect(
res,
`invalid insert ${JSON.stringify(invalidInsert)} pass instead of fail`
).to.undefined;
}
it('create table with raw check on table', async () => {
await knex.schema.dropTableIfExists('check_test');
await knex.schema
.createTable('check_test', function (table) {
table.string('col1');
table.string('col2');
table.check('?? = ??', ['col1', 'col2']);
})
.testSql((tester) => {
tester(
['pg', 'pg-redshift', 'cockroachdb'],
[
'create table "check_test" ("col1" varchar(255), "col2" varchar(255), check ("col1" = "col2"))',
]
);
tester(
['oracledb'],
[
'create table "check_test" ("name" varchar2(255) check ("name" LIKE \'%val%\'))',
]
);
tester('mysql', [
'create table `check_test` (`col1` varchar(255), `col2` varchar(255), check (`col1` = `col2`)) default character set utf8',
]);
tester('sqlite3', [
'create table `check_test` (`col1` varchar(255), `col2` varchar(255), check (`col1` = `col2`))',
]);
tester('mssql', [
'CREATE TABLE [check_test] ([col1] nvarchar(255), [col2] nvarchar(255), check ([col1] = [col2]))',
]);
});
await checkTest(
{ col1: 'test', col2: 'test' },
{ col1: 'test', col2: 'test2' }
);
});
it('create table with numeric positive check', async () => {
await knex.schema.dropTableIfExists('check_test');
await knex.schema
.createTable('check_test', function (table) {
table.integer('price').checkPositive();
})
.testSql((tester) => {
tester(
['pg', 'pg-redshift', 'cockroachdb', 'oracledb'],
[
'create table "check_test" ("price" integer check ("price" > 0))',
]
);
tester('mysql', [
'create table `check_test` (`price` int check (`price` > 0)) default character set utf8',
]);
tester('sqlite3', [
'create table `check_test` (`price` integer check (`price` > 0))',
]);
tester('mssql', [
'CREATE TABLE [check_test] ([price] int check ([price] > 0))',
]);
});
await checkTest({ price: 10 }, { price: -5 });
});
it('create table with numeric negative check', async () => {
await knex.schema.dropTableIfExists('check_test');
await knex.schema
.createTable('check_test', function (table) {
table.integer('price').checkNegative();
})
.testSql((tester) => {
tester(
['pg', 'pg-redshift', 'cockroachdb', 'oracledb'],
[
'create table "check_test" ("price" integer check ("price" < 0))',
]
);
tester('mysql', [
'create table `check_test` (`price` int check (`price` < 0)) default character set utf8',
]);
tester('sqlite3', [
'create table `check_test` (`price` integer check (`price` < 0))',
]);
tester('mssql', [
'CREATE TABLE [check_test] ([price] int check ([price] < 0))',
]);
});
await checkTest({ price: -5 }, { price: 10 });
});
it('create table with check in', async () => {
await knex.schema.dropTableIfExists('check_test');
await knex.schema
.createTable('check_test', function (table) {
table.string('animal').checkIn(['dog', 'cat']);
})
.testSql((tester) => {
tester(
['pg', 'pg-redshift', 'cockroachdb'],
[
'create table "check_test" ("animal" varchar(255) check ("animal" in (\'dog\',\'cat\')))',
]
);
tester('oracledb', [
'create table "check_test" ("animal" varchar2(255) check ("animal" in (\'dog\', \'cat\')))',
]);
tester('mysql', [
"create table `check_test` (`animal` varchar(255) check (`animal` in ('dog','cat'))) default character set utf8",
]);
tester('sqlite3', [
"create table `check_test` (`animal` varchar(255) check (`animal` in ('dog','cat')))",
]);
tester('mssql', [
"CREATE TABLE [check_test] ([animal] nvarchar(255) check ([animal] in ('dog','cat')))",
]);
});
await checkTest({ animal: 'dog' }, { animal: 'pig' });
await checkTest({ animal: 'cat' }, { animal: 'pig' });
});
it('create table with check not in', async () => {
await knex.schema.dropTableIfExists('check_test');
await knex.schema
.createTable('check_test', function (table) {
table.string('animal').checkNotIn(['dog', 'cat']);
})
.testSql((tester) => {
tester(
['pg', 'pg-redshift', 'cockroachdb'],
[
'create table "check_test" ("animal" varchar(255) check ("animal" not in (\'dog\',\'cat\')))',
]
);
tester('oracledb', [
'create table "check_test" ("animal" varchar2(255) check ("animal" not in (\'dog\',\'cat\')))',
]);
tester('mysql', [
"create table `check_test` (`animal` varchar(255) check (`animal` not in ('dog','cat'))) default character set utf8",
]);
tester('sqlite3', [
"create table `check_test` (`animal` varchar(255) check (`animal` not in ('dog','cat')))",
]);
tester('mssql', [
"CREATE TABLE [check_test] ([animal] nvarchar(255) check ([animal] not in ('dog','cat')))",
]);
});
await checkTest({ animal: 'pg' }, { animal: 'cat' });
await checkTest({ animal: 'mammoth' }, { animal: 'cat' });
});
it('create table with check between', async () => {
await knex.schema.dropTableIfExists('check_test');
await knex.schema
.createTable('check_test', function (table) {
table.integer('price').checkBetween([10, 20]);
})
.testSql((tester) => {
tester(
['pg', 'pg-redshift', 'cockroachdb', 'oracledb'],
[
'create table "check_test" ("price" integer check ("price" between 10 and 20))',
]
);
tester('mysql', [
'create table `check_test` (`price` int check (`price` between 10 and 20)) default character set utf8',
]);
tester('sqlite3', [
'create table `check_test` (`price` integer check (`price` between 10 and 20))',
]);
tester('mssql', [
'CREATE TABLE [check_test] ([price] int check ([price] between 10 and 20))',
]);
});
await checkTest({ price: 10 }, { price: 25 });
});
it('create table with check between with multiple intervals', async () => {
await knex.schema.dropTableIfExists('check_test');
await knex.schema
.createTable('check_test', function (table) {
table.integer('price').checkBetween([
[10, 20],
[30, 40],
]);
})
.testSql((tester) => {
tester(
['pg', 'pg-redshift', 'cockroachdb', 'oracledb'],
[
'create table "check_test" ("price" integer check ("price" between 10 and 20 or "price" between 30 and 40))',
]
);
tester('mysql', [
'create table `check_test` (`price` int check (`price` between 10 and 20 or `price` between 30 and 40)) default character set utf8',
]);
tester('sqlite3', [
'create table `check_test` (`price` integer check (`price` between 10 and 20 or `price` between 30 and 40))',
]);
tester('mssql', [
'CREATE TABLE [check_test] ([price] int check ([price] between 10 and 20 or [price] between 30 and 40))',
]);
});
await checkTest({ price: 15 }, { price: 25 });
await checkTest({ price: 35 }, { price: 45 });
});
it('create table with check length', async () => {
await knex.schema.dropTableIfExists('check_test');
await knex.schema
.createTable('check_test', function (table) {
table.string('year').checkLength('=', 4);
})
.testSql((tester) => {
tester(
['pg', 'pg-redshift', 'cockroachdb'],
[
'create table "check_test" ("year" varchar(255) check (length("year") = 4))',
]
);
tester('oracledb', [
'create table "check_test" ("year" varchar2(255) check (length("year") = 4))',
]);
tester('mysql', [
'create table `check_test` (`year` varchar(255) check (length(`year`) = 4)) default character set utf8',
]);
tester('sqlite3', [
'create table `check_test` (`year` varchar(255) check (length(`year`) = 4))',
]);
tester('mssql', [
'CREATE TABLE [check_test] ([year] nvarchar(255) check (LEN([year]) = 4))',
]);
});
await checkTest({ year: '2021' }, { year: '21' });
});
it('create table with check regex', async function () {
if (isMssql(knex) || isSQLite(knex)) {
this.skip();
}
await knex.schema.dropTableIfExists('check_test');
await knex.schema
.createTable('check_test', function (table) {
table.string('date').checkRegex('[0-9]{2}-[0-9]{2}-[0-9]{4}');
})
.testSql((tester) => {
tester(
['pg', 'pg-redshift', 'cockroachdb'],
[
'create table "check_test" ("date" varchar(255) check ("date" ~ \'[0-9]{2}-[0-9]{2}-[0-9]{4}\'))',
]
);
tester('oracledb', [
'create table "check_test" ("date" varchar2(255) check (REGEXP_LIKE("date",\'[0-9]{2}-[0-9]{2}-[0-9]{4}\')))',
]);
tester('mysql', [
"create table `check_test` (`date` varchar(255) check (`date` REGEXP '[0-9]{2}-[0-9]{2}-[0-9]{4}')) default character set utf8",
]);
});
await checkTest({ date: '01-02-2021' }, { date: '01/02/2021' });
await checkTest({ date: '01-02-2021' }, { date: '01-02-221' });
});
it('drop checks', async function () {
if (isSQLite(knex)) {
this.skip();
}
await knex.schema.dropTableIfExists('check_test');
await knex.schema.createTable('check_test', function (table) {
table.integer('price').checkPositive('price_pos_check');
});
await checkTest({ price: 10 }, { price: -5 });
await knex.schema
.table('check_test', function (table) {
table.dropChecks('price_pos_check');
})
.testSql((tester) => {
tester(
['pg', 'pg-redshift', 'cockroachdb', 'oracledb'],
['alter table "check_test" drop constraint price_pos_check']
);
tester('mysql', [
'alter table `check_test` drop constraint price_pos_check',
]);
});
// Now, insert negative value work.
expect(await knex('check_test').insert([{ price: -5 }])).to.not.throw;
});
it('create table with custom check', async function () {
await knex.schema.dropTableIfExists('check_test');
await knex.schema
.createTable('check_test', (table) => {
table.integer('price_min');
table.integer('price_max');
table
.check(
'?? < ??',
['price_min', 'price_max'],
'price_min_lower_max'
)
.check('?? > 5', ['price_min']);
})
.testSql((tester) => {
tester(
['pg', 'pg-redshift', 'cockroachdb'],
[
'create table "check_test" ("price_min" integer, "price_max" integer, constraint price_min_lower_max check ("price_min" < "price_max"), check ("price_min" > 5))',
]
);
tester('oracledb', [
'create table "check_test" ("price_min" integer, "price_max" integer, constraint price_min_lower_max check ("price_min" < "price_max"), check ("price_min" > 5))',
]);
tester('mysql', [
'create table `check_test` (`price_min` int, `price_max` int, constraint price_min_lower_max check (`price_min` < `price_max`), check (`price_min` > 5)) default character set utf8',
]);
tester('mssql', [
'CREATE TABLE [check_test] ([price_min] int, [price_max] int, constraint price_min_lower_max check ([price_min] < [price_max]), check ([price_min] > 5))',
]);
});
await checkTest(
{ price_min: 10, price_max: 20 },
{ price_min: 10, price_max: 5 }
);
await checkTest(
{ price_min: 10, price_max: 20 },
{ price_min: 0, price_max: 5 }
);
});
it('create table with checks then alter', async function () {
if (isSQLite(knex)) {
this.skip();
}
await knex.schema.dropTableIfExists('check_test');
await knex.schema.createTable('check_test', (table) => {
table.integer('price');
});
expect(await knex('check_test').insert([{ price: -5 }])).to.not.throw;
// Alter table with check constraint fail, we have row that violated the constraint
let error;
try {
await knex.schema.table('check_test', (table) => {
table.integer('price').checkPositive().alter();
});
} catch (e) {
error = e;
}
expect(error.message).to.not.undefined;
// empty the table to add the constraint
await knex('check_test').truncate();
await knex.schema
.table('check_test', (table) => {
table.integer('price').checkPositive().alter();
})
.testSql((tester) => {
tester(
['pg', 'pg-redshift'],
[
'alter table "check_test" alter column "price" drop default',
'alter table "check_test" alter column "price" drop not null',
'alter table "check_test" alter column "price" type integer using ("price"::integer)',
'alter table "check_test" add constraint check_test_price_1 check("price" > 0)',
]
);
tester('cockroachdb', [
'SET enable_experimental_alter_column_type_general = true',
'alter table "check_test" alter column "price" drop default',
'alter table "check_test" alter column "price" drop not null',
'alter table "check_test" alter column "price" type integer using ("price"::integer)',
'alter table "check_test" add constraint check_test_price_1 check("price" > 0)',
]);
tester('oracledb', [
'alter table "check_test" modify "price" integer',
'alter table "check_test" add constraint check_test_price_1 check("price" > 0)',
]);
tester('mysql', [
'alter table `check_test` modify `price` int',
'alter table `check_test` add constraint check_test_price_1 check(`price` > 0)',
]);
});
await checkTest({ price: 10 }, { price: -10 });
});
});
});
});

View File

@ -1357,5 +1357,131 @@ describe('MSSQL SchemaBuilder', function () {
expect(spy.secondCall.args).to.deep.equal(['email', 'email context']);
expect(spy.thirdCall.args).to.deep.equal(['users', 'table context']);
});
describe('Checks tests', function () {
it('allows adding checks positive', function () {
tableSql = client
.schemaBuilder()
.table('user', function (t) {
t.integer('price').checkPositive();
})
.toSQL();
expect(tableSql[0].sql).to.equal(
'ALTER TABLE [user] ADD [price] int check ([price] > 0)'
);
});
it('allows adding checks negative', function () {
tableSql = client
.schemaBuilder()
.table('user', function (t) {
t.integer('price').checkNegative();
})
.toSQL();
expect(tableSql[0].sql).to.equal(
'ALTER TABLE [user] ADD [price] int check ([price] < 0)'
);
});
it('allows adding checks in', function () {
tableSql = client
.schemaBuilder()
.table('user', function (t) {
t.string('animal').checkIn(['cat', 'dog']);
})
.toSQL();
expect(tableSql[0].sql).to.equal(
"ALTER TABLE [user] ADD [animal] nvarchar(255) check ([animal] in ('cat','dog'))"
);
});
it('allows adding checks not in', function () {
tableSql = client
.schemaBuilder()
.table('user', function (t) {
t.string('animal').checkNotIn(['cat', 'dog']);
})
.toSQL();
expect(tableSql[0].sql).to.equal(
"ALTER TABLE [user] ADD [animal] nvarchar(255) check ([animal] not in ('cat','dog'))"
);
});
it('allows adding checks between', function () {
tableSql = client
.schemaBuilder()
.table('user', function (t) {
t.integer('price').checkBetween([10, 15]);
})
.toSQL();
expect(tableSql[0].sql).to.equal(
'ALTER TABLE [user] ADD [price] int check ([price] between 10 and 15)'
);
});
it('allows adding checks between with multiple intervals', function () {
tableSql = client
.schemaBuilder()
.table('user', function (t) {
t.integer('price').checkBetween([
[10, 15],
[20, 25],
]);
})
.toSQL();
expect(tableSql[0].sql).to.equal(
'ALTER TABLE [user] ADD [price] int check ([price] between 10 and 15 or [price] between 20 and 25)'
);
});
it('allows adding checks between strings', function () {
tableSql = client
.schemaBuilder()
.table('user', function (t) {
t.integer('price').checkBetween(['banana', 'orange']);
})
.toSQL();
expect(tableSql[0].sql).to.equal(
"ALTER TABLE [user] ADD [price] int check ([price] between 'banana' and 'orange')"
);
});
it('allows length equals', function () {
tableSql = client
.schemaBuilder()
.table('user', function (t) {
t.varchar('phone').checkLength('=', 8);
})
.toSQL();
expect(tableSql[0].sql).to.equal(
'ALTER TABLE [user] ADD [phone] nvarchar(255) check (LEN([phone]) = 8)'
);
});
it('check regexp', function () {
tableSql = client
.schemaBuilder()
.table('user', function (t) {
// MSSQL only support simple pattern matching but not regex syntax.
t.varchar('phone').checkRegex('[0-9][0-9][0-9]');
})
.toSQL();
expect(tableSql[0].sql).to.equal(
"ALTER TABLE [user] ADD [phone] nvarchar(255) check ([phone] LIKE '%[0-9][0-9][0-9]%')"
);
});
it('drop checks', function () {
tableSql = client
.schemaBuilder()
.table('user', function (t) {
t.dropChecks(['check_constraint1', 'check_constraint2']);
})
.toSQL();
expect(tableSql[0].sql).to.equal(
'alter table [user] drop constraint check_constraint1, drop constraint check_constraint2'
);
});
});
});
});

View File

@ -1443,5 +1443,130 @@ module.exports = function (dialect) {
expect(spy.thirdCall.args).to.deep.equal(['users', 'table context']);
});
});
describe('Checks tests', function () {
it('allows adding checks positive', function () {
tableSql = client
.schemaBuilder()
.table('user', function (t) {
t.integer('price').checkPositive();
})
.toSQL();
expect(tableSql[0].sql).to.equal(
'alter table `user` add `price` int check (`price` > 0)'
);
});
it('allows adding checks negative', function () {
tableSql = client
.schemaBuilder()
.table('user', function (t) {
t.integer('price').checkNegative();
})
.toSQL();
expect(tableSql[0].sql).to.equal(
'alter table `user` add `price` int check (`price` < 0)'
);
});
it('allows adding checks in', function () {
tableSql = client
.schemaBuilder()
.table('user', function (t) {
t.string('animal').checkIn(['cat', 'dog']);
})
.toSQL();
expect(tableSql[0].sql).to.equal(
"alter table `user` add `animal` varchar(255) check (`animal` in ('cat','dog'))"
);
});
it('allows adding checks not in', function () {
tableSql = client
.schemaBuilder()
.table('user', function (t) {
t.string('animal').checkNotIn(['cat', 'dog']);
})
.toSQL();
expect(tableSql[0].sql).to.equal(
"alter table `user` add `animal` varchar(255) check (`animal` not in ('cat','dog'))"
);
});
it('allows adding checks between', function () {
tableSql = client
.schemaBuilder()
.table('user', function (t) {
t.integer('price').checkBetween([10, 15]);
})
.toSQL();
expect(tableSql[0].sql).to.equal(
'alter table `user` add `price` int check (`price` between 10 and 15)'
);
});
it('allows adding checks between with multiple intervals', function () {
tableSql = client
.schemaBuilder()
.table('user', function (t) {
t.integer('price').checkBetween([
[10, 15],
[20, 25],
]);
})
.toSQL();
expect(tableSql[0].sql).to.equal(
'alter table `user` add `price` int check (`price` between 10 and 15 or `price` between 20 and 25)'
);
});
it('allows adding checks between strings', function () {
tableSql = client
.schemaBuilder()
.table('user', function (t) {
t.integer('price').checkBetween(['banana', 'orange']);
})
.toSQL();
expect(tableSql[0].sql).to.equal(
"alter table `user` add `price` int check (`price` between 'banana' and 'orange')"
);
});
it('allows length equals', function () {
tableSql = client
.schemaBuilder()
.table('user', function (t) {
t.varchar('phone').checkLength('=', 8);
})
.toSQL();
expect(tableSql[0].sql).to.equal(
'alter table `user` add `phone` varchar(255) check (length(`phone`) = 8)'
);
});
it('check regexp', function () {
tableSql = client
.schemaBuilder()
.table('user', function (t) {
t.varchar('phone').checkRegex('[0-9]{8}');
})
.toSQL();
expect(tableSql[0].sql).to.equal(
"alter table `user` add `phone` varchar(255) check (`phone` REGEXP '[0-9]{8}')"
);
});
it('drop checks', function () {
tableSql = client
.schemaBuilder()
.table('user', function (t) {
t.dropChecks(['check_constraint1', 'check_constraint2']);
})
.toSQL();
expect(tableSql[0].sql).to.equal(
'alter table `user` drop constraint check_constraint1, drop constraint check_constraint2'
);
});
});
});
};

View File

@ -1240,4 +1240,129 @@ describe('OracleDb SchemaBuilder', function () {
'begin execute immediate \'drop table "book"\'; exception when others then if sqlcode != -942 then raise; end if; end;\nbegin execute immediate \'drop sequence "book_seq"\'; exception when others then if sqlcode != -2289 then raise; end if; end;'
);
});
describe('Checks tests', function () {
it('allows adding checks positive', function () {
tableSql = client
.schemaBuilder()
.table('user', function (t) {
t.integer('price').checkPositive();
})
.toSQL();
expect(tableSql[0].sql).to.equal(
'alter table "user" add "price" integer check ("price" > 0)'
);
});
it('allows adding checks negative', function () {
tableSql = client
.schemaBuilder()
.table('user', function (t) {
t.integer('price').checkNegative();
})
.toSQL();
expect(tableSql[0].sql).to.equal(
'alter table "user" add "price" integer check ("price" < 0)'
);
});
it('allows adding checks in', function () {
tableSql = client
.schemaBuilder()
.table('user', function (t) {
t.string('animal').checkIn(['cat', 'dog']);
})
.toSQL();
expect(tableSql[0].sql).to.equal(
'alter table "user" add "animal" varchar2(255) check ("animal" in (\'cat\', \'dog\'))'
);
});
it('allows adding checks not in', function () {
tableSql = client
.schemaBuilder()
.table('user', function (t) {
t.string('animal').checkNotIn(['cat', 'dog']);
})
.toSQL();
expect(tableSql[0].sql).to.equal(
'alter table "user" add "animal" varchar2(255) check ("animal" not in (\'cat\',\'dog\'))'
);
});
it('allows adding checks between', function () {
tableSql = client
.schemaBuilder()
.table('user', function (t) {
t.integer('price').checkBetween([10, 15]);
})
.toSQL();
expect(tableSql[0].sql).to.equal(
'alter table "user" add "price" integer check ("price" between 10 and 15)'
);
});
it('allows adding checks between with multiple intervals', function () {
tableSql = client
.schemaBuilder()
.table('user', function (t) {
t.integer('price').checkBetween([
[10, 15],
[20, 25],
]);
})
.toSQL();
expect(tableSql[0].sql).to.equal(
'alter table "user" add "price" integer check ("price" between 10 and 15 or "price" between 20 and 25)'
);
});
it('allows adding checks between strings', function () {
tableSql = client
.schemaBuilder()
.table('user', function (t) {
t.integer('price').checkBetween(['banana', 'orange']);
})
.toSQL();
expect(tableSql[0].sql).to.equal(
'alter table "user" add "price" integer check ("price" between \'banana\' and \'orange\')'
);
});
it('allows length equals', function () {
tableSql = client
.schemaBuilder()
.table('user', function (t) {
t.varchar('phone').checkLength('=', 8);
})
.toSQL();
expect(tableSql[0].sql).to.equal(
'alter table "user" add "phone" varchar2(255) check (length("phone") = 8)'
);
});
it('check regexp', function () {
tableSql = client
.schemaBuilder()
.table('user', function (t) {
t.varchar('phone').checkRegex('[0-9]{8}');
})
.toSQL();
expect(tableSql[0].sql).to.equal(
'alter table "user" add "phone" varchar2(255) check (REGEXP_LIKE("phone",\'[0-9]{8}\'))'
);
});
it('drop checks', function () {
tableSql = client
.schemaBuilder()
.table('user', function (t) {
t.dropChecks(['check_constraint1', 'check_constraint2']);
})
.toSQL();
expect(tableSql[0].sql).to.equal(
'alter table "user" drop constraint check_constraint1, drop constraint check_constraint2'
);
});
});
});

View File

@ -201,6 +201,19 @@ describe('PostgreSQL SchemaBuilder', function () {
);
});
it('alter table with checks', function () {
tableSql = client
.schemaBuilder()
.table('users', function (table) {
table.integer('price').checkPositive();
})
.toSQL();
equal(1, tableSql.length);
expect(tableSql[0].sql).to.equal(
'alter table "users" add column "price" integer check ("price" > 0)'
);
});
it('drop table', function () {
tableSql = client.schemaBuilder().dropTable('users').toSQL();
equal(1, tableSql.length);
@ -2005,4 +2018,129 @@ describe('PostgreSQL SchemaBuilder', function () {
]);
});
});
describe('Checks tests', function () {
it('allows adding checks positive', function () {
tableSql = client
.schemaBuilder()
.table('user', function (t) {
t.integer('price').checkPositive();
})
.toSQL();
expect(tableSql[0].sql).to.equal(
'alter table "user" add column "price" integer check ("price" > 0)'
);
});
it('allows adding checks negative', function () {
tableSql = client
.schemaBuilder()
.table('user', function (t) {
t.integer('price').checkNegative();
})
.toSQL();
expect(tableSql[0].sql).to.equal(
'alter table "user" add column "price" integer check ("price" < 0)'
);
});
it('allows adding checks in', function () {
tableSql = client
.schemaBuilder()
.table('user', function (t) {
t.string('animal').checkIn(['cat', 'dog']);
})
.toSQL();
expect(tableSql[0].sql).to.equal(
'alter table "user" add column "animal" varchar(255) check ("animal" in (\'cat\',\'dog\'))'
);
});
it('allows adding checks not in', function () {
tableSql = client
.schemaBuilder()
.table('user', function (t) {
t.string('animal').checkNotIn(['cat', 'dog']);
})
.toSQL();
expect(tableSql[0].sql).to.equal(
'alter table "user" add column "animal" varchar(255) check ("animal" not in (\'cat\',\'dog\'))'
);
});
it('allows adding checks between', function () {
tableSql = client
.schemaBuilder()
.table('user', function (t) {
t.integer('price').checkBetween([10, 15]);
})
.toSQL();
expect(tableSql[0].sql).to.equal(
'alter table "user" add column "price" integer check ("price" between 10 and 15)'
);
});
it('allows adding checks between with multiple intervals', function () {
tableSql = client
.schemaBuilder()
.table('user', function (t) {
t.integer('price').checkBetween([
[10, 15],
[20, 25],
]);
})
.toSQL();
expect(tableSql[0].sql).to.equal(
'alter table "user" add column "price" integer check ("price" between 10 and 15 or "price" between 20 and 25)'
);
});
it('allows adding checks between strings', function () {
tableSql = client
.schemaBuilder()
.table('user', function (t) {
t.integer('price').checkBetween(['banana', 'orange']);
})
.toSQL();
expect(tableSql[0].sql).to.equal(
'alter table "user" add column "price" integer check ("price" between \'banana\' and \'orange\')'
);
});
it('allows length equals', function () {
tableSql = client
.schemaBuilder()
.table('user', function (t) {
t.varchar('phone').checkLength('=', 8);
})
.toSQL();
expect(tableSql[0].sql).to.equal(
'alter table "user" add column "phone" varchar(255) check (length("phone") = 8)'
);
});
it('check regexp', function () {
tableSql = client
.schemaBuilder()
.table('user', function (t) {
t.varchar('phone').checkRegex('[0-9]{8}');
})
.toSQL();
expect(tableSql[0].sql).to.equal(
'alter table "user" add column "phone" varchar(255) check ("phone" ~ \'[0-9]{8}\')'
);
});
it('drop checks', function () {
tableSql = client
.schemaBuilder()
.table('user', function (t) {
t.dropChecks(['check_constraint1', 'check_constraint2']);
})
.toSQL();
expect(tableSql[0].sql).to.equal(
'alter table "user" drop constraint check_constraint1, drop constraint check_constraint2'
);
});
});
});

View File

@ -1001,4 +1001,129 @@ describe('Redshift SchemaBuilder', function () {
'alter table "users" add constraint "testconstraintname" primary key ("test")'
);
});
describe('Checks tests', function () {
it('allows adding checks positive', function () {
tableSql = client
.schemaBuilder()
.table('user', function (t) {
t.integer('price').checkPositive();
})
.toSQL();
expect(tableSql[0].sql).to.equal(
'alter table "user" add column "price" integer check ("price" > 0)'
);
});
it('allows adding checks negative', function () {
tableSql = client
.schemaBuilder()
.table('user', function (t) {
t.integer('price').checkNegative();
})
.toSQL();
expect(tableSql[0].sql).to.equal(
'alter table "user" add column "price" integer check ("price" < 0)'
);
});
it('allows adding checks in', function () {
tableSql = client
.schemaBuilder()
.table('user', function (t) {
t.string('animal').checkIn(['cat', 'dog']);
})
.toSQL();
expect(tableSql[0].sql).to.equal(
'alter table "user" add column "animal" varchar(255) check ("animal" in (\'cat\',\'dog\'))'
);
});
it('allows adding checks not in', function () {
tableSql = client
.schemaBuilder()
.table('user', function (t) {
t.string('animal').checkNotIn(['cat', 'dog']);
})
.toSQL();
expect(tableSql[0].sql).to.equal(
'alter table "user" add column "animal" varchar(255) check ("animal" not in (\'cat\',\'dog\'))'
);
});
it('allows adding checks between', function () {
tableSql = client
.schemaBuilder()
.table('user', function (t) {
t.integer('price').checkBetween([10, 15]);
})
.toSQL();
expect(tableSql[0].sql).to.equal(
'alter table "user" add column "price" integer check ("price" between 10 and 15)'
);
});
it('allows adding checks between with multiple intervals', function () {
tableSql = client
.schemaBuilder()
.table('user', function (t) {
t.integer('price').checkBetween([
[10, 15],
[20, 25],
]);
})
.toSQL();
expect(tableSql[0].sql).to.equal(
'alter table "user" add column "price" integer check ("price" between 10 and 15 or "price" between 20 and 25)'
);
});
it('allows adding checks between strings', function () {
tableSql = client
.schemaBuilder()
.table('user', function (t) {
t.integer('price').checkBetween(['banana', 'orange']);
})
.toSQL();
expect(tableSql[0].sql).to.equal(
'alter table "user" add column "price" integer check ("price" between \'banana\' and \'orange\')'
);
});
it('allows length equals', function () {
tableSql = client
.schemaBuilder()
.table('user', function (t) {
t.varchar('phone').checkLength('=', 8);
})
.toSQL();
expect(tableSql[0].sql).to.equal(
'alter table "user" add column "phone" varchar(255) check (length("phone") = 8)'
);
});
it('check regexp', function () {
tableSql = client
.schemaBuilder()
.table('user', function (t) {
t.varchar('phone').checkRegex('[0-9]{8}');
})
.toSQL();
expect(tableSql[0].sql).to.equal(
'alter table "user" add column "phone" varchar(255) check ("phone" ~ \'[0-9]{8}\')'
);
});
it('drop checks', function () {
tableSql = client
.schemaBuilder()
.table('user', function (t) {
t.dropChecks(['check_constraint1', 'check_constraint2']);
})
.toSQL();
expect(tableSql[0].sql).to.equal(
'alter table "user" drop constraint check_constraint1, drop constraint check_constraint2'
);
});
});
});

View File

@ -4475,5 +4475,130 @@ describe('SQLite parser and compiler', function () {
expect(parsedSql).to.equal(newSql);
});
describe('Checks tests', function () {
it('allows adding checks positive', function () {
tableSql = client
.schemaBuilder()
.table('user', function (t) {
t.integer('price').checkPositive();
})
.toSQL();
expect(tableSql[0].sql).to.equal(
'alter table `user` add column `price` integer check (`price` > 0)'
);
});
it('allows adding checks negative', function () {
tableSql = client
.schemaBuilder()
.table('user', function (t) {
t.integer('price').checkNegative();
})
.toSQL();
expect(tableSql[0].sql).to.equal(
'alter table `user` add column `price` integer check (`price` < 0)'
);
});
it('allows adding checks in', function () {
tableSql = client
.schemaBuilder()
.table('user', function (t) {
t.string('animal').checkIn(['cat', 'dog']);
})
.toSQL();
expect(tableSql[0].sql).to.equal(
"alter table `user` add column `animal` varchar(255) check (`animal` in ('cat','dog'))"
);
});
it('allows adding checks not in', function () {
tableSql = client
.schemaBuilder()
.table('user', function (t) {
t.string('animal').checkNotIn(['cat', 'dog']);
})
.toSQL();
expect(tableSql[0].sql).to.equal(
"alter table `user` add column `animal` varchar(255) check (`animal` not in ('cat','dog'))"
);
});
it('allows adding checks between', function () {
tableSql = client
.schemaBuilder()
.table('user', function (t) {
t.integer('price').checkBetween([10, 15]);
})
.toSQL();
expect(tableSql[0].sql).to.equal(
'alter table `user` add column `price` integer check (`price` between 10 and 15)'
);
});
it('allows adding checks between with multiple intervals', function () {
tableSql = client
.schemaBuilder()
.table('user', function (t) {
t.integer('price').checkBetween([
[10, 15],
[20, 25],
]);
})
.toSQL();
expect(tableSql[0].sql).to.equal(
'alter table `user` add column `price` integer check (`price` between 10 and 15 or `price` between 20 and 25)'
);
});
it('allows adding checks between strings', function () {
tableSql = client
.schemaBuilder()
.table('user', function (t) {
t.integer('price').checkBetween(['banana', 'orange']);
})
.toSQL();
expect(tableSql[0].sql).to.equal(
"alter table `user` add column `price` integer check (`price` between 'banana' and 'orange')"
);
});
it('allows length equals', function () {
tableSql = client
.schemaBuilder()
.table('user', function (t) {
t.varchar('phone').checkLength('=', 8);
})
.toSQL();
expect(tableSql[0].sql).to.equal(
'alter table `user` add column `phone` varchar(255) check (length(`phone`) = 8)'
);
});
it('check regexp', function () {
tableSql = client
.schemaBuilder()
.table('user', function (t) {
t.varchar('phone').checkRegex('[0-9]{8}');
})
.toSQL();
expect(tableSql[0].sql).to.equal(
"alter table `user` add column `phone` varchar(255) check (`phone` REGEXP '[0-9]{8}')"
);
});
it('drop checks', function () {
tableSql = client
.schemaBuilder()
.table('user', function (t) {
t.dropChecks(['check_constraint1', 'check_constraint2']);
})
.toSQL();
expect(tableSql[0].sql).to.equal(
'alter table `user` drop constraint check_constraint1, drop constraint check_constraint2'
);
});
});
});
});

11
types/index.d.ts vendored
View File

@ -2148,11 +2148,13 @@ export declare namespace Knex {
columns: readonly string[],
foreignKeyName?: string
): MultikeyForeignConstraintBuilder;
check(checkPredicate: string, bindings?: Record<string, any>, constraintName?: string): TableBuilder;
dropForeign(columnNames: string | readonly string[], foreignKeyName?: string): TableBuilder;
dropUnique(columnNames: readonly (string | Raw)[], indexName?: string): TableBuilder;
dropPrimary(constraintName?: string): TableBuilder;
dropIndex(columnNames: string | readonly (string | Raw)[], indexName?: string): TableBuilder;
dropTimestamps(useCamelCase?: boolean): TableBuilder;
dropChecks(checkConstraintNames: string | string[]): TableBuilder;
queryContext(context: any): TableBuilder;
}
@ -2185,6 +2187,7 @@ export declare namespace Knex {
type deferrableType = 'not deferrable' | 'immediate' | 'deferred';
type storageEngineIndexType = 'hash' | 'btree';
type lengthOperator = '>' | '<' | '<=' | '>=' | '!=' | '=';
interface ColumnBuilder {
index(indexName?: string): ColumnBuilder;
@ -2205,7 +2208,15 @@ export declare namespace Knex {
queryContext(context: any): ColumnBuilder;
after(columnName: string): ColumnBuilder;
first(): ColumnBuilder;
checkPositive(constraintName?: string): ColumnBuilder;
checkNegative(constraintName?: string): ColumnBuilder;
checkIn(values: string[], constraintName?: string): ColumnBuilder;
checkNotIn(values: string[], constraintName?: string): ColumnBuilder;
checkBetween(values: any[] | any[][], constraintName?: string): ColumnBuilder;
checkLength(operator: lengthOperator, length: number, constraintName?: string): ColumnBuilder;
checkRegex(regex: string, constraintName?: string): ColumnBuilder;
}
interface ForeignConstraintBuilder {
references(columnName: string): ReferencingColumnBuilder;
}