diff --git a/README.md b/README.md
index ede7d60..bcd67cb 100644
--- a/README.md
+++ b/README.md
@@ -150,6 +150,14 @@ that you require.
String |
Username to connect to database |
+
+ allowExtendedOperators |
+ Boolean |
+ Set to true to enable MySQL-specific operators
+ such as match . Learn more in
+ Extended operators below.
+ |
+
@@ -498,6 +506,55 @@ last_modified: Date;
- GEOMETRY
- JSON
+## Extended operators
+MySQL connector supports the following MySQL-specific operators:
+- [`match`](#operator-match)
+Please note extended operators are disabled by default, you must enable
+them at datasource level or model level by setting `allowExtendedOperators` to
+`true`.
+### Operator `match`
+The `match` operator allows you to perform a full text search using the [MATCH() .. AGAINST()](https://dev.mysql.com/doc/refman/8.0/en/fulltext-search.html) operator in MySQL.
+
+Three different modes of the `MATCH` clause are also available in the form of operators -
+
+- `matchbool` for [Boolean Full Text Search](https://dev.mysql.com/doc/refman/8.0/en/fulltext-boolean.html)
+- `matchnl` for [Natural Language Full Text Search](https://dev.mysql.com/doc/refman/8.0/en/fulltext-natural-language.html)
+- `matchqe` for [Full-Text Searches with Query Expansion](https://dev.mysql.com/doc/refman/8.0/en/fulltext-query-expansion.html)
+- `matchnlqe` for [Full-Text Searches with Query Expansion](https://dev.mysql.com/doc/refman/8.0/en/fulltext-query-expansion.html) with the `IN NATURAL LANGUAGE MODE WITH QUERY EXPANSION` modifier.
+
+By default, the `match` operator works in Natural Language mode.
+
+**Note** The fields you are querying must be setup with a `FULLTEXT` index to perform full text search on them.
+Assuming a model such as this:
+```ts
+@model({
+ settings: {
+ allowExtendedOperators: true,
+ }
+})
+class Post {
+ @property({
+ type: 'string',
+ mysql: {
+ index: {
+ kind: 'FULLTEXT'
+ }
+ },
+ })
+ content: string;
+}
+```
+You can query the content field as follows:
+```ts
+const posts = await postRepository.find({
+ where: {
+ {
+ content: {match: 'someString'},
+ }
+ }
+});
+```
+
## Discovery and auto-migration
### Model discovery
diff --git a/lib/mysql.js b/lib/mysql.js
index 5d40131..21e4331 100644
--- a/lib/mysql.js
+++ b/lib/mysql.js
@@ -269,7 +269,7 @@ MySQL.prototype._modifyOrCreate = function(model, data, options, fields, cb) {
for (let i = 0, n = fields.names.length; i < n; i++) {
if (!fields.properties[i].id) {
setValues.push(new ParameterizedSQL(fields.names[i] + '=' +
- columnValues[i].sql, columnValues[i].params));
+ columnValues[i].sql, columnValues[i].params));
}
}
@@ -313,10 +313,10 @@ MySQL.prototype.replaceOrCreate = function(model, data, options, cb) {
* @param {Function} [cb] The callback function
*/
MySQL.prototype.save =
-MySQL.prototype.updateOrCreate = function(model, data, options, cb) {
- const fields = this.buildFields(model, data);
- this._modifyOrCreate(model, data, options, fields, cb);
-};
+ MySQL.prototype.updateOrCreate = function(model, data, options, cb) {
+ const fields = this.buildFields(model, data);
+ this._modifyOrCreate(model, data, options, fields, cb);
+ };
MySQL.prototype.getInsertedId = function(model, info) {
const insertedId = info && typeof info.insertId === 'number' ?
@@ -550,25 +550,52 @@ MySQL.prototype.ping = function(cb) {
MySQL.prototype.buildExpression = function(columnName, operator, operatorValue,
propertyDefinition) {
- if (operator === 'regexp') {
- let clause = columnName + ' REGEXP ?';
- // By default, MySQL regexp is not case sensitive. (https://dev.mysql.com/doc/refman/5.7/en/regexp.html)
- // To allow case sensitive regexp query, it has to be binded to a `BINARY` type.
- // If ignore case is not specified, search it as case sensitive.
- if (!operatorValue.ignoreCase) {
- clause = columnName + ' REGEXP BINARY ?';
- }
+ let clause;
+ switch (operator) {
+ case 'regexp':
+ clause = columnName + ' REGEXP ?';
+ // By default, MySQL regexp is not case sensitive. (https://dev.mysql.com/doc/refman/5.7/en/regexp.html)
+ // To allow case sensitive regexp query, it has to be binded to a `BINARY` type.
+ // If ignore case is not specified, search it as case sensitive.
+ if (!operatorValue.ignoreCase) {
+ clause = columnName + ' REGEXP BINARY ?';
+ }
- if (operatorValue.ignoreCase)
- g.warn('{{MySQL}} {{regex}} syntax does not respect the {{`i`}} flag');
- if (operatorValue.global)
- g.warn('{{MySQL}} {{regex}} syntax does not respect the {{`g`}} flag');
+ if (operatorValue.ignoreCase)
+ g.warn('{{MySQL}} {{regex}} syntax does not respect the {{`i`}} flag');
+ if (operatorValue.global)
+ g.warn('{{MySQL}} {{regex}} syntax does not respect the {{`g`}} flag');
- if (operatorValue.multiline)
- g.warn('{{MySQL}} {{regex}} syntax does not respect the {{`m`}} flag');
+ if (operatorValue.multiline)
+ g.warn('{{MySQL}} {{regex}} syntax does not respect the {{`m`}} flag');
- return new ParameterizedSQL(clause,
- [operatorValue.source]);
+ return new ParameterizedSQL(clause,
+ [operatorValue.source]);
+ case 'matchnl':
+ case 'matchqe':
+ case 'matchnlqe':
+ case 'matchbool':
+ case 'match':
+ let mode;
+ switch (operator) {
+ case 'matchbool':
+ mode = ' IN BOOLEAN MODE';
+ break;
+ case 'matchnl':
+ mode = ' IN NATURAL LANGUAGE MODE';
+ break;
+ case 'matchqe':
+ mode = ' WITH QUERY EXPANSION';
+ break;
+ case 'matchnlqe':
+ mode = ' IN NATURAL LANGUAGE MODE WITH QUERY EXPANSION';
+ break;
+ default:
+ mode = '';
+ }
+ clause = ` MATCH (${columnName}) AGAINST (?${mode})`;
+
+ return new ParameterizedSQL(clause, [operatorValue]);
}
// invoke the base implementation of `buildExpression`
diff --git a/test/mysql.test.js b/test/mysql.test.js
index e5c1231..6632973 100644
--- a/test/mysql.test.js
+++ b/test/mysql.test.js
@@ -37,6 +37,17 @@ describe('mysql', function() {
userId: ObjectID,
}, {
forceId: false,
+ indexes: {
+ content_fts_index: {
+ kind: 'FULLTEXT',
+ columns: 'content',
+ },
+ title_fts_index: {
+ kind: 'FULLTEXT',
+ columns: 'title',
+ },
+ },
+ allowExtendedOperators: true,
});
PostWithStringId = db.define('PostWithStringId', {
@@ -912,6 +923,105 @@ describe('mysql', function() {
});
});
+ context('match operator', function() {
+ beforeEach(function deleteExistingTestFixtures(done) {
+ Post.destroyAll(done);
+ });
+ beforeEach(function createTestFixtures(done) {
+ Post.create([
+ {title: 'About Redis', content: 'Redis is a Database'},
+ {title: 'Usage', content: 'How To Use MySQL database Well'},
+ {title: 'About Mysql', content: 'Mysql is a database'},
+ ], done);
+ });
+ after(function deleteTestFixtures(done) {
+ Post.destroyAll(done);
+ });
+
+ context('with one column and string', () => {
+ it('should work', function(done) {
+ Post.find({where: {content: {match: '+using MYSQL'}}}, (err, posts) => {
+ should.not.exist(err);
+ should.exist(posts);
+ posts.length.should.equal(2);
+ done();
+ });
+ });
+ it('should work in boolean mode with empty result expected', function(done) {
+ Post.find({where: {content: {matchbool: '+using MYSQL'}}}, (err, posts) => {
+ should.not.exist(err);
+ should.exist(posts);
+ posts.length.should.equal(0);
+ done();
+ });
+ });
+ it('should work in boolean mode with one result expected', function(done) {
+ Post.find({where: {content: {matchbool: '+use MYSQL'}}}, (err, posts) => {
+ should.not.exist(err);
+ should.exist(posts);
+ posts.length.should.equal(1);
+ done();
+ });
+ });
+ it('should work with matchqe operator with expected result in first and second pass', function(done) {
+ Post.find({where: {content: {match: 'redis'}}}, (err, posts) => {
+ should.not.exist(err);
+ should.exist(posts);
+ posts.length.should.equal(1);
+ Post.find({where: {content: {matchqe: 'redis'}}}, (err, expandedPosts) => {
+ should.not.exist(err);
+ should.exist(expandedPosts);
+ expandedPosts.length.should.equal(3);
+ done();
+ });
+ });
+ });
+ it('should work with matchnlqe operator with expected result in first and second pass', function(done) {
+ Post.find({where: {content: {match: 'redis'}}}, (err, posts) => {
+ should.not.exist(err);
+ should.exist(posts);
+ posts.length.should.equal(1);
+ Post.find({where: {content: {matchnlqe: 'redis'}}}, (err, expandedPosts) => {
+ should.not.exist(err);
+ should.exist(expandedPosts);
+ expandedPosts.length.should.equal(3);
+ done();
+ });
+ });
+ });
+ });
+
+ context('with multiple column and one string', () => {
+ it('should work', function(done) {
+ const against = 'using MYSQL';
+ Post.find(
+ {
+ where: {
+ or: [
+ {
+ content: {
+ match: against,
+ },
+ },
+ {
+ title: {
+ match: against,
+ },
+ },
+ ],
+ },
+ },
+ (err, posts) => {
+ should.not.exist(err);
+ should.exist(posts);
+ posts.length.should.equal(2);
+ done();
+ },
+ );
+ });
+ });
+ });
+
function deleteAllModelInstances() {
const models = [
Post, PostWithStringId, PostWithUniqueTitle, PostWithNumId, Student,