Skip to content

Commit 18e04a2

Browse files
Scott Rochafelixfbecker
authored andcommitted
feat(operators): Add $regexp operator (#7855)
Adds $regexp operator for MySQL and Postgres and its negated and case-insensitive versions.
1 parent 0528f39 commit 18e04a2

File tree

9 files changed

+257
-3
lines changed

9 files changed

+257
-3
lines changed

docs/querying.md

Lines changed: 4 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -135,6 +135,10 @@ $like: '%hat', // LIKE '%hat'
135135
$notLike: '%hat' // NOT LIKE '%hat'
136136
$iLike: '%hat' // ILIKE '%hat' (case insensitive) (PG only)
137137
$notILike: '%hat' // NOT ILIKE '%hat' (PG only)
138+
$regexp: '^[h|a|t]' // REGEXP/~ '^[h|a|t]' (MySQL/PG only)
139+
$notRegexp: '^[h|a|t]' // NOT REGEXP/!~ '^[h|a|t]' (MySQL/PG only)
140+
$iRegexp: '^[h|a|t]' // ~* '^[h|a|t]' (PG only)
141+
$notIRegexp: '^[h|a|t]' // !~* '^[h|a|t]' (PG only)
138142
$like: { $any: ['cat', 'hat']}
139143
// LIKE ANY ARRAY['cat', 'hat'] - also works for iLike and notLike
140144
$overlap: [1, 2] // && [1, 2] (PG array overlap operator)

lib/dialects/abstract/query-generator.js

Lines changed: 19 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -1977,6 +1977,10 @@ const QueryGenerator = {
19771977
$notLike: 'NOT LIKE',
19781978
$iLike: 'ILIKE',
19791979
$notILike: 'NOT ILIKE',
1980+
$regexp: '~',
1981+
$notRegexp: '!~',
1982+
$iRegexp: '~*',
1983+
$notIRegexp: '!~*',
19801984
$between: 'BETWEEN',
19811985
$notBetween: 'NOT BETWEEN',
19821986
$overlap: '&&',
@@ -2282,7 +2286,20 @@ const QueryGenerator = {
22822286
comparator = 'IS NOT';
22832287
}
22842288

2289+
if (comparator.indexOf('~') !== -1) {
2290+
escapeValue = false;
2291+
}
2292+
2293+
if (this._dialect.name === 'mysql') {
2294+
if (comparator === '~') {
2295+
comparator = 'REGEXP';
2296+
} else if (comparator === '!~') {
2297+
comparator = 'NOT REGEXP';
2298+
}
2299+
}
2300+
22852301
escapeOptions.acceptStrings = comparator.indexOf('LIKE') !== -1;
2302+
escapeOptions.acceptRegExp = comparator.indexOf('~') !== -1 || comparator.indexOf('REGEXP') !== -1;
22862303

22872304
if (escapeValue) {
22882305
value = this.escape(value, field, escapeOptions);
@@ -2291,6 +2308,8 @@ const QueryGenerator = {
22912308
if (escapeOptions.acceptStrings && comparator.indexOf('ANY') > comparator.indexOf('LIKE')) {
22922309
value = '(' + value + ')';
22932310
}
2311+
} else if (escapeOptions.acceptRegExp) {
2312+
value = '\'' + value + '\'';
22942313
}
22952314
}
22962315

lib/dialects/mysql/index.js

Lines changed: 2 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -41,7 +41,8 @@ MysqlDialect.prototype.supports = _.merge(_.cloneDeep(AbstractDialect.prototype.
4141
updateOnDuplicate: true,
4242
indexViaAlter: true,
4343
NUMERIC: true,
44-
GEOMETRY: true
44+
GEOMETRY: true,
45+
REGEXP: true
4546
});
4647

4748
ConnectionManager.prototype.defaultVersion = '5.6.0';

lib/dialects/postgres/index.js

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -44,6 +44,7 @@ PostgresDialect.prototype.supports = _.merge(_.cloneDeep(AbstractDialect.prototy
4444
ARRAY: true,
4545
RANGE: true,
4646
GEOMETRY: true,
47+
REGEXP: true,
4748
GEOGRAPHY: true,
4849
JSON: true,
4950
JSONB: true,

lib/model.js

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -1406,7 +1406,7 @@ class Model {
14061406
* ```sql
14071407
* WHERE attr1 > 50 AND attr2 <= 45 AND attr3 IN (1,2,3) AND attr4 != 5
14081408
* ```
1409-
* Possible options are: `$ne, $in, $not, $notIn, $gte, $gt, $lte, $lt, $like, $ilike/$iLike, $notLike, $notILike, '..'/$between, '!..'/$notBetween, '&&'/$overlap, '@>'/$contains, '<@'/$contained`
1409+
* Possible options are: `$ne, $in, $not, $notIn, $gte, $gt, $lte, $lt, $like, $ilike/$iLike, $notLike, $notILike, $regexp, $notRegexp, '..'/$between, '!..'/$notBetween, '&&'/$overlap, '@>'/$contains, '<@'/$contained`
14101410
*
14111411
* __Queries using OR__
14121412
* ```js
Lines changed: 128 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,128 @@
1+
'use strict';
2+
3+
const chai = require('chai'),
4+
Sequelize = require('../../../../index'),
5+
Promise = Sequelize.Promise,
6+
expect = chai.expect,
7+
Support = require(__dirname + '/../../support'),
8+
DataTypes = require(__dirname + '/../../../../lib/data-types'),
9+
dialect = Support.getTestDialect();
10+
11+
describe(Support.getTestDialectTeaser('Model'), () => {
12+
describe('attributes', () => {
13+
describe('operators', () => {
14+
describe('REGEXP', () => {
15+
beforeEach(function() {
16+
const queryInterface = this.sequelize.getQueryInterface();
17+
18+
this.User = this.sequelize.define('user', {
19+
id: {
20+
type: DataTypes.INTEGER,
21+
allowNull: false,
22+
primaryKey: true,
23+
autoIncrement: true,
24+
field: 'userId'
25+
},
26+
name: {
27+
type: DataTypes.STRING,
28+
field: 'full_name'
29+
}
30+
}, {
31+
tableName: 'users',
32+
timestamps: false
33+
});
34+
35+
return Promise.all([
36+
queryInterface.createTable('users', {
37+
userId: {
38+
type: DataTypes.INTEGER,
39+
allowNull: false,
40+
primaryKey: true,
41+
autoIncrement: true
42+
},
43+
full_name: {
44+
type: DataTypes.STRING
45+
}
46+
})
47+
]);
48+
});
49+
50+
if (dialect === 'mysql' || dialect === 'postgres') {
51+
it('should work with a regexp where', function() {
52+
const self = this;
53+
54+
return this.User.create({
55+
name: 'Foobar'
56+
}).then(() => {
57+
return self.User.find({
58+
where: {
59+
name: {
60+
$regexp: '^Foo'
61+
}
62+
}
63+
});
64+
}).then(user => {
65+
expect(user).to.be.ok;
66+
});
67+
});
68+
69+
it('should work with a not regexp where', function() {
70+
const self = this;
71+
72+
return this.User.create({
73+
name: 'Foobar'
74+
}).then(() => {
75+
return self.User.find({
76+
where: {
77+
name: {
78+
$notRegexp: '^Foo'
79+
}
80+
}
81+
});
82+
}).then(user => {
83+
expect(user).to.not.be.ok;
84+
});
85+
});
86+
87+
if (dialect === 'postgres') {
88+
it('should work with a case-insensitive regexp where', function() {
89+
const self = this;
90+
91+
return this.User.create({
92+
name: 'Foobar'
93+
}).then(() => {
94+
return self.User.find({
95+
where: {
96+
name: {
97+
$iRegexp: '^foo'
98+
}
99+
}
100+
});
101+
}).then(user => {
102+
expect(user).to.be.ok;
103+
});
104+
});
105+
106+
it('should work with a case-insensitive not regexp where', function() {
107+
const self = this;
108+
109+
return this.User.create({
110+
name: 'Foobar'
111+
}).then(() => {
112+
return self.User.find({
113+
where: {
114+
name: {
115+
$notIRegexp: '^foo'
116+
}
117+
}
118+
});
119+
}).then(user => {
120+
expect(user).to.not.be.ok;
121+
});
122+
});
123+
}
124+
}
125+
});
126+
});
127+
});
128+
});

test/unit/dialects/mysql/query-generator.test.js

Lines changed: 10 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -381,6 +381,16 @@ if (dialect === 'mysql') {
381381
arguments: ['myTable', {where: {field: {not: 3}}}],
382382
expectation: 'SELECT * FROM `myTable` WHERE `myTable`.`field` != 3;',
383383
context: QueryGenerator
384+
}, {
385+
title: 'Regular Expression in where clause',
386+
arguments: ['myTable', {where: {field: {$regexp: '^[h|a|t]'}}}],
387+
expectation: "SELECT * FROM `myTable` WHERE `myTable`.`field` REGEXP '^[h|a|t]';",
388+
context: QueryGenerator
389+
}, {
390+
title: 'Regular Expression negation in where clause',
391+
arguments: ['myTable', {where: {field: {$notRegexp: '^[h|a|t]'}}}],
392+
expectation: "SELECT * FROM `myTable` WHERE `myTable`.`field` NOT REGEXP '^[h|a|t]';",
393+
context: QueryGenerator
384394
}
385395
],
386396

test/unit/dialects/postgres/query-generator.test.js

Lines changed: 20 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -502,6 +502,26 @@ if (dialect.match(/^postgres/)) {
502502
arguments: ['myTable', {where: {field: {not: 3}}}],
503503
expectation: 'SELECT * FROM myTable WHERE myTable.field != 3;',
504504
context: {options: {quoteIdentifiers: false}}
505+
}, {
506+
title: 'Regular Expression in where clause',
507+
arguments: ['myTable', {where: {field: {$regexp: '^[h|a|t]'}}}],
508+
expectation: "SELECT * FROM \"myTable\" WHERE \"myTable\".\"field\" ~ '^[h|a|t]';",
509+
context: QueryGenerator
510+
}, {
511+
title: 'Regular Expression negation in where clause',
512+
arguments: ['myTable', {where: {field: {$notRegexp: '^[h|a|t]'}}}],
513+
expectation: "SELECT * FROM \"myTable\" WHERE \"myTable\".\"field\" !~ '^[h|a|t]';",
514+
context: QueryGenerator
515+
}, {
516+
title: 'Case-insensitive Regular Expression in where clause',
517+
arguments: ['myTable', {where: {field: {$iRegexp: '^[h|a|t]'}}}],
518+
expectation: "SELECT * FROM \"myTable\" WHERE \"myTable\".\"field\" ~* '^[h|a|t]';",
519+
context: QueryGenerator
520+
}, {
521+
title: 'Case-insensitive Regular Expression negation in where clause',
522+
arguments: ['myTable', {where: {field: {$notIRegexp: '^[h|a|t]'}}}],
523+
expectation: "SELECT * FROM \"myTable\" WHERE \"myTable\".\"field\" !~* '^[h|a|t]';",
524+
context: QueryGenerator
505525
}
506526
],
507527

@@ -615,7 +635,6 @@ if (dialect.match(/^postgres/)) {
615635
expectation: "INSERT INTO mySchema.myTable (name) VALUES ('foo'';DROP TABLE mySchema.myTable;');",
616636
context: {options: {quoteIdentifiers: false}}
617637
}
618-
619638
],
620639

621640
bulkInsertQuery: [

test/unit/sql/where.test.js

Lines changed: 72 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -908,6 +908,78 @@ suite(Support.getTestDialectTeaser('SQL'), () => {
908908
});
909909
}
910910

911+
if (current.dialect.supports.REGEXP) {
912+
suite('$regexp', () => {
913+
testsql('username', {
914+
$regexp: '^sw.*r$'
915+
}, {
916+
mysql: "`username` REGEXP '^sw.*r$'",
917+
postgres: '"username" ~ \'^sw.*r$\''
918+
});
919+
});
920+
921+
suite('$regexp', () => {
922+
testsql('newline', {
923+
$regexp: '^new\nline$'
924+
}, {
925+
mysql: "`newline` REGEXP '^new\nline$'",
926+
postgres: '"newline" ~ \'^new\nline$\''
927+
});
928+
});
929+
930+
suite('$notRegexp', () => {
931+
testsql('username', {
932+
$notRegexp: '^sw.*r$'
933+
}, {
934+
mysql: "`username` NOT REGEXP '^sw.*r$'",
935+
postgres: '"username" !~ \'^sw.*r$\''
936+
});
937+
});
938+
939+
suite('$notRegexp', () => {
940+
testsql('newline', {
941+
$notRegexp: '^new\nline$'
942+
}, {
943+
mysql: "`newline` NOT REGEXP '^new\nline$'",
944+
postgres: '"newline" !~ \'^new\nline$\''
945+
});
946+
});
947+
948+
if (current.dialect.name === 'postgres') {
949+
suite('$iRegexp', () => {
950+
testsql('username', {
951+
$iRegexp: '^sw.*r$'
952+
}, {
953+
postgres: '"username" ~* \'^sw.*r$\''
954+
});
955+
});
956+
957+
suite('$iRegexp', () => {
958+
testsql('newline', {
959+
$iRegexp: '^new\nline$'
960+
}, {
961+
postgres: '"newline" ~* \'^new\nline$\''
962+
});
963+
});
964+
965+
suite('$notIRegexp', () => {
966+
testsql('username', {
967+
$notIRegexp: '^sw.*r$'
968+
}, {
969+
postgres: '"username" !~* \'^sw.*r$\''
970+
});
971+
});
972+
973+
suite('$notIRegexp', () => {
974+
testsql('newline', {
975+
$notIRegexp: '^new\nline$'
976+
}, {
977+
postgres: '"newline" !~* \'^new\nline$\''
978+
});
979+
});
980+
}
981+
}
982+
911983
suite('fn', () => {
912984
test('{name: this.sequelize.fn(\'LOWER\', \'DERP\')}', function() {
913985
expectsql(sql.whereQuery({name: this.sequelize.fn('LOWER', 'DERP')}), {

0 commit comments

Comments
 (0)