MATCH
On this page
For columnstore tables created with a FULLTEXT index, the text columns in that table can be searched by using the MATCH AGAINST
syntax.
The result of the MATCH
statement is a relevancy score between 0 and 1, which indicates the quality of the match.
Important
To include recent inserts/updates from the hidden rowstore table in with the results, run OPTIMIZE TABLE tbl_
before running your query.
Refer to Working with Full-Text Search for more conceptual information on this feature.
Syntax
The full-text search MATCH
syntax is:
MATCH (<column1>,<column2>,...) AGAINST (<expression>)
The columns specified in a MATCH
clause must be from the same table .
Operators
The AGAINST
expression consists of a mix of text with zero or more of the following operators.
Operator |
Description |
---|---|
(no operator) |
When no operator is specified, the word is optional; however, the rows that contain it are rated higher. |
+ |
A leading plus sign indicates that this word must be present in each row returned. |
- |
A leading minus sign indicates that this word must not be present in any of the rows that are returned. |
NOT |
The |
AND |
The |
OR |
The |
() |
Parentheses group words into subexpressions. |
*, ? |
See the Wildcard support section below. |
"" |
A phrase that is enclosed within double quote (") characters matches the words in the quotes as if it is a single word. |
~ |
The tilde symbol is used to support fuzzy searches. |
Note
SingleStore supports only constant expressions (search filters) inside the AGAINST
clause, for example, a regular expression like (Stock*)
or a constant string like "DBC".AGAINST
expressions at runtime.
Stopwords
Certain words are ignored by full-text search due to their commonality resulting in less relevant results.
a, an, and, are, as, at, be, but, by, for, if, in, into, is, it, no, not,
of, on, or, such, that, the, their, then, there, these, they, this, to, was, will, with
Wildcard Support
Single and multiple character wildcard searches within single terms are supported (not within phrase queries).
To perform a single character wildcard search use the ?
symbol and to perform a multiple character wildcard search use the *
symbol.
The single character wildcard search looks for terms that match that with the single character replaced.text
or test
you can use the search: te?t
Multiple character wildcard searches looks for zero or more characters.test*
You can also use the wildcard searches in the middle of a term.te*t
Important
Neither ?
or *
are supported at the beginning of a term.
Special Characters
Depending on the use case, FULLTEXT
matching may not always be compatible with match expressions involving special characters.FULLTEXT
removes special characters from the search.
+ - && || ! ( ) { } [ ] ^ " ~ * ? : \
Relevancy Score
The relevancy score of an expression in a MATCH
statement denotes the ranking of the expression based on the following factors:
-
Number of times an expression appears in a column.
More occurrences of an expression in the matched column(s) increases its relevancy score. -
Rarity of the expression.
Rare words have a higher relevancy score than commonly used words. -
The length of the column containing the expression.
A column with a short expression has a higher relevancy score than a column with a long expression.
Full-Text Legacy Version 1 Examples
Create a Table with a Full-Text Index
CREATE TABLE articles (id INT UNSIGNED,year int UNSIGNED,title VARCHAR(200),body TEXT,SORT KEY (id),FULLTEXT (title, body));
Use a SQL Predicate
SELECT count(*)FROM articlesWHERE year = 2017 AND MATCH (body) AGAINST ('memsql');
Search for the Word database
across Two Columns
SELECT * FROM articlesWHERE MATCH (title,body)AGAINST ('database');
Use a Single Operator
SELECT titleFROM articlesWHERE MATCH (title) AGAINST ('Database OR "Business Intelligence"');
Use Multiple Operators
The following example returns the title of an article that contains either database
or Business Intelligence
and the string real-time analytics
in the body.real time
and real-time
will be included.
SELECT titleFROM articlesWHERE MATCH (title) AGAINST ('Database OR "Business Intelligence"')AND MATCH(body) AGAINST ("real-time analytics");
Use a Wildcard
This example uses the wildcard ’*’ to return all articles with titles starting with the word Journal
such as Journalism
, Journalist
, Journals
, and so on.
SELECT *FROM articlesWHERE MATCH(title) AGAINST ('Journal*');
Create a Relevance Score as an Output Column
SELECT id, title, MATCH(body) AGAINST ('database') relevanceFROM articlesWHERE MATCH(body) AGAINST ('database');
Search with a Specific Relevance Score
SELECT id, title, MATCH(body) AGAINST ('database')FROM articlesWHERE MATCH(body) AGAINST ('database') > .12;
UPDATE or DELETE Queries
UPDATE articles set name = concat(name,".DATABASE") where MATCH(body) AGAINST ('database');
DELETE from articles where MATCH(body) AGAINST ('database');
Related Topics
Last modified: October 2, 2024