- MySQL Naming Rules
- The Server SQL Mode
- Character Set Support
- Selecting, Creating, Dropping, and Altering Databases
- Creating, Dropping, Indexing, and Altering Tables
- Getting Information About Databases and Tables
- Performing Multiple-Table Retrievals with Joins
- Performing Multiple-Table Retrievals with Subqueries
- Performing Multiple-Table Retrievals with UNION
- Multiple-Table Deletes and Updates
- Performing Transactions
- Foreign Keys and Referential Integrity
- Using FULLTEXT Searches
- New Features in MySQL 5.0
Using FULLTEXT Searches
MySQL includes the capability for performing full text searches. The full-text search engine allows you to look for words or phrases without using pattern-matching operations. There are three kinds of full-text search:
Natural language searching. The search string is parsed into words and the search looks for records containing these words.
Boolean mode searching. The search string is parsed into words, but words can be modified by operator characters that indicate specific requirements such as that a given word should be present or absent in matching records, or that records must contain an exact phrase.
Query expansion searching. This kind of search occurs in two phases. The first phase is a natural language search. Then a second search is done using the original search string concatenated with the most highly relevant matching records from the first search. This expands the search on the basis of the assumption that words related to the original search string will match relevant records that the original string did not.
Full-text search capability is enabled for a given table by creating a special kind of index and has the following characteristics:
Full-text searches are based on FULLTEXT indexes, which can be created only for MyISAM tables. Only CHAR, VARCHAR, and TEXT columns can be included in a FULLTEXT index.
Common words are ignored for FULLTEXT searches, where "common" means "present in at least half the records." It's especially important to remember this when you're setting up a test table to experiment with the FULLTEXT capability. Be sure to insert at least three records into your test table. If the table has just one or two records, every word in it will occur at least 50% of the time and you'll never get any results!
There is a built-in list of common words such as "the," "after," and "other" that are called "stopwords" and that are always ignored.
Words that are too short also are ignored. By default, "too short" is defined as fewer than four characters, but you can reconfigure the server to set the minimum length to a different value.
Words are defined as sequences of characters that include letters, digits, apostrophes, and underscores. This means that a string like "full-blooded" is considered to contain two words, "full" and "blooded." Normally, a full-text search matches whole words, not partial words, and the FULLTEXT engine considers a record to match a search string if it includes any of the words in the search string. A variant form of search called a boolean full-text search allows you to impose the additional constraint that all the words must be present (either in any order, or, to perform a phrase search, in exactly the order listed in the search string, including any punctuation). With a boolean search, it's also possible to match records that do not include certain words, or to add a wildcard modifier to match all words that begin with a given prefix.
A FULLTEXT index can be created for a single column or multiple columns. If it spans multiple columns, searches based on the index look through all the columns simultaneously. The flip side of this is that when you perform a search, you must specify a column list that corresponds exactly to the set of columns that matches some FULLTEXT index. For example, if you want to search col1 sometimes, col2 sometimes, and both col1 and col2 sometimes, you should have three indexes: one for each of the columns separately, and one that includes both columns.
The following examples show how to use full-text searching by creating FULLTEXT indexes and then performing queries on them using the MATCH operator. A script to create the table and some sample data to load into it are available in the fulltext directory of the sampdb distribution.
A FULLTEXT index is created much the same way as other indexes. That is, you can define it with CREATE TABLE when creating the table initially, or add it afterward with ALTER TABLE or CREATE INDEX. Because FULLTEXT indexes require you to use MyISAM tables, you can take advantage of one of the properties of the MyISAM storage engine if you're creating a new table to use for FULLTEXT searches: Table loading proceeds more quickly if you populate the table first and then add the indexes afterward, rather than loading data into an already indexed table. Suppose that you have a data file named apothegm.txt containing famous sayings and the people to whom they're attributed:
Aeschylus Time as he grows old teaches many lessons Alexander Graham Bell Mr. Watson, come here. I want you! Benjamin Franklin It is hard for an empty bag to stand upright Benjamin Franklin Little strokes fell great oaks Benjamin Franklin Remember that time is money Miguel de Cervantes Bell, book, and candle Proverbs 15:1 A soft answer turneth away wrath Theodore Roosevelt Speak softly and carry a big stick William Shakespeare But, soft! what light through yonder window breaks? Robert Burton I light my candle from their torches.
If you want to search by phrase and attribution separately or together, you need to index each column separately, and also create an index that includes both columns. You can create, populate, and index a table named apothegm as follows:
CREATE TABLE apothegm (attribution VARCHAR(40), phrase TEXT) ENGINE = MyISAM; LOAD DATA LOCAL INFILE 'apothegm.txt' INTO TABLE apothegm; ALTER TABLE apothegm ADD FULLTEXT (phrase), ADD FULLTEXT (attribution), ADD FULLTEXT (phrase, attribution);
Natural Language FULLTEXT Searches
After setting up the table, perform natural language full-text searches on it using MATCH to name the column or columns to search and AGAINST() to specify the search string. For example:
mysql> SELECT * FROM apothegm WHERE MATCH(attribution) AGAINST('roosevelt'); +--------------------+------------------------------------+ | attribution | phrase | +--------------------+------------------------------------+ | Theodore Roosevelt | Speak softly and carry a big stick | +--------------------+------------------------------------+ mysql> SELECT * FROM apothegm WHERE MATCH(phrase) AGAINST('time'); +-------------------+-------------------------------------------+ | attribution | phrase | +-------------------+-------------------------------------------+ | Benjamin Franklin | Remember that time is money | | Aeschylus | Time as he grows old teaches many lessons | +-------------------+-------------------------------------------+ mysql> SELECT * FROM apothegm WHERE MATCH(attribution, phrase) -> AGAINST('bell'); +-----------------------+------------------------------------+ | attribution | phrase | +-----------------------+------------------------------------+ | Alexander Graham Bell | Mr. Watson, come here. I want you! | | Miguel de Cervantes | Bell, book, and candle | +-----------------------+------------------------------------+
In the last example, note how the query finds records that contain the search word in different columns, which demonstrates the FULLTEXT capability of searching multiple columns at once. Also note that the order of the columns as named in the query is attribution, phrase. That differs from the order in which they were named when the index was created (phrase, attribution), which illustrates that order does not matter. What matters is that there must be some FULLTEXT index that consists of exactly the columns named.
If you just want to see how many records a search matches, use COUNT(*):
mysql> SELECT COUNT(*) FROM apothegm WHERE MATCH(phrase) AGAINST('time'); +----------+ | COUNT(*) | +----------+ | 2 | +----------+
Output rows for natural language FULLTEXT searches are ordered by decreasing relevance when you use a MATCH expression in the WHERE clause. Relevance values are non-negative floating point values, with zero indicating "no relevance." To see these values, use a MATCH expression in the output column list:
mysql> SELECT phrase, MATCH(phrase) AGAINST('time') AS relevance -> FROM apothegm; +-----------------------------------------------------+-----------------+ | phrase | relevance | +-----------------------------------------------------+-----------------+ | Time as he grows old teaches many lessons | 1.3253291845322 | | Mr. Watson, come here. I want you! | 0 | | It is hard for an empty bag to stand upright | 0 | | Little strokes fell great oaks | 0 | | Remember that time is money | 1.3400621414185 | | Bell, book, and candle | 0 | | A soft answer turneth away wrath | 0 | | Speak softly and carry a big stick | 0 | | But, soft! what light through yonder window breaks? | 0 | | I light my candle from their torches. | 0 | +-----------------------------------------------------+-----------------+
A natural language search finds records that contain any of the search words, so a query such as the following returns records with either "hard" or "soft":
mysql> SELECT * FROM apothegm WHERE MATCH(phrase) -> AGAINST('hard soft'); +---------------------+-----------------------------------------------------+ | attribution | phrase | +---------------------+-----------------------------------------------------+ | Benjamin Franklin | It is hard for an empty bag to stand upright | | Proverbs 15:1 | A soft answer turneth away wrath | | William Shakespeare | But, soft! what light through yonder window breaks? | +---------------------+-----------------------------------------------------+
Boolean Mode FULLTEXT Searches
Greater control over multiple-word matching can be obtained by using boolean mode FULLTEXT searches. This type of search is performed by adding IN BOOLEAN MODE after the search string in the AGAINST() function. Boolean searches have the following characteristics:
-
The 50% rule is ignored; searches find words even if they occur in more than half of the records.
-
Results are not sorted by relevance.
-
Modifiers may be applied to words in the search string. A leading plus or minus sign requires a word to be present or not present in matching records. For example, a search string of 'bell' matches records that contain "bell," but a search string of '+bell -candle' in boolean mode matches only records that contain "bell" and do not contain "candle."
mysql> SELECT * FROM apothegm -> WHERE MATCH(attribution, phrase) -> AGAINST('bell'); +-----------------------+------------------------------------+ | attribution | phrase | +-----------------------+------------------------------------+ | Alexander Graham Bell | Mr. Watson, come here. I want you! | | Miguel de Cervantes | Bell, book, and candle | +-----------------------+------------------------------------+ mysql> SELECT * FROM apothegm -> WHERE MATCH(attribution, phrase) -> AGAINST('+bell -candle' IN BOOLEAN MODE); +-----------------------+------------------------------------+ | attribution | phrase | +-----------------------+------------------------------------+ | Alexander Graham Bell | Mr. Watson, come here. I want you! | +-----------------------+------------------------------------+
A trailing asterisk acts as a wildcard so that any record containing words beginning with the search word match. For example 'soft*' matches "soft," "softly," "softness," and so forth:
mysql> SELECT * FROM apothegm WHERE MATCH(phrase) -> AGAINST('soft*' IN BOOLEAN MODE); +---------------------+-----------------------------------------------------+ | attribution | phrase | +---------------------+-----------------------------------------------------+ | Proverbs 15:1 | A soft answer turneth away wrath | | William Shakespeare | But, soft! what light through yonder window breaks? | | Theodore Roosevelt | Speak softly and carry a big stick | +---------------------+-----------------------------------------------------+
However, the wildcard feature cannot be used to match words shorter than the minimum index word length.
The full set of boolean mode modifiers is listed under the entry for MATCH in Appendix C, "Operator and Function Reference."
Stop words are ignored just as for natural language searches, even if marked as required. A search for '+Alexander +the +great' finds records containing "Alexander" and "great," but ignores "the" as a stopword.
A phrase search can be performed to require all words to be present in a particular order. Enclose the phrase within double quotes, and include punctuation and whitespace that is present in the phrase you want to match. In other words, you must specify the exact phrase:
mysql> SELECT * FROM apothegm -> WHERE MATCH(attribution, phrase) -> AGAINST('"bell book and candle"' IN BOOLEAN MODE); Empty set (0.00 sec) mysql> SELECT * FROM apothegm -> WHERE MATCH(attribution, phrase) -> AGAINST('"bell, book, and candle"' IN BOOLEAN MODE); +---------------------+------------------------+ | attribution | phrase | +---------------------+------------------------+ | Miguel de Cervantes | Bell, book, and candle | +---------------------+------------------------+
If you want to use IN BOOLEAN MODE searches with tables that were initially created before that capability was added (MySQL 4.0.2), you must rebuild the indexes entirely. Do so like this:
REPAIR TABLE tbl_name USE_FRM;
It's possible to perform a boolean mode full-text search on columns that are not part of a FULLTEXT index, although this is much slower than using indexed columns.
Query Expansion FULLTEXT Searches
A full-text search with query expansion performs a two-phase search. The initial search is like a regular natural language search. Then the most highly relevant records from this search are used for the second phase. The words in these records are used along with the original search terms to perform a second search. Because the set of search terms is larger, the result generally includes records that are not found in the first phase but are related to them.
To perform this kind of search, add WITH QUERY EXPANSION following the search terms. The following example provides an illustration. The first query shows a natural language search. The second query shows a query expansion search. Its result includes an extra record that contains none of the original search terms. This record is found because it contains the word "candle" that is present in one of the records found by the natural language search.
mysql> SELECT * FROM apothegm -> WHERE MATCH(attribution, phrase) -> AGAINST('bell book'); +-----------------------+------------------------------------+ | attribution | phrase | +-----------------------+------------------------------------+ | Miguel de Cervantes | Bell, book, and candle | | Alexander Graham Bell | Mr. Watson, come here. I want you! | +-----------------------+------------------------------------+ mysql> SELECT * FROM apothegm -> WHERE MATCH(attribution, phrase) -> AGAINST('bell book' WITH QUERY EXPANSION); +-----------------------+---------------------------------------+ | attribution | phrase | +-----------------------+---------------------------------------+ | Miguel de Cervantes | Bell, book, and candle | | Alexander Graham Bell | Mr. Watson, come here. I want you! | | Robert Burton | I light my candle from their torches. | +-----------------------+---------------------------------------+
Configuring the FULLTEXT Search Engine
Several full-text parameters are configurable and can be modified by setting system variables. The parameters that determine the shortest and longest words to index in FULLTEXT indexes are ft_min_word_len and ft_max_word_len. Words with lengths outside the range defined by these two variables are ignored when FULLTEXT indexes are built. The default minimum value is 4. The default maximum value depends on your server version. Currently in MySQL 4.1, the maximum is 84.
Suppose that you want to change the minimum word length from 4 to 3. Do so like this:
-
Start the server with the ft_min_word_len variable set to 3. To ensure that this happens whenever the server starts, it's best to place the setting in an option file such as /etc/my.cnf:
-
For any existing tables that already have FULLTEXT indexes, you must rebuild those indexes. You can drop and add the indexes, but it's easier and sufficient to perform a quick repair operation:
-
Any new FULLTEXT indexes that you create after changing the parameter will use the new value automatically.
[mysqld] set-variable = ft_min_word_len=3
REPAIR TABLE tbl_name QUICK;
For more information on setting system variables, see Appendix D. For details on using option files, see Appendix F.
Note: If you use myisamchk to rebuild indexes for a table that contains any FULLTEXT indexes, see the FULLTEXT-related notes in the myisamchk description in Appendix F.