One of my customers wants to search for names in a table. But sometimes the search is case insensitive, next time search should be done case sensitive. The index on that column always is created with the collation of the column. And if you search with a different collation in mind, you end up with a full table scan. Here is an example:
The problem
mysql> SHOW CREATE TABLE City\G
*************************** 1. row ***************************
Table: City
Create Table: CREATE TABLE `City` (
`ID` int(11) NOT NULL AUTO_INCREMENT,
`Name` char(35) CHARACTER SET utf8 COLLATE utf8_bin DEFAULT NULL,
`CountryCode` char(3) NOT NULL DEFAULT '',
`District` char(20) NOT NULL DEFAULT '',
`Population` int(11) NOT NULL DEFAULT '0',
PRIMARY KEY (`ID`),
KEY `CountryCode` (`CountryCode`),
KEY `Name` (`Name`),
) ENGINE=InnoDB AUTO_INCREMENT=4080 DEFAULT CHARSET=latin1
1 row in set (0,00 sec)
The collation of the column `Name` is utf8_bin, so case sensitive. Let's search for a City:
mysql> SELECT Name,Population FROM City WHERE Name='berlin';
Empty set (0,00 sec)
mysql> EXPLAIN SELECT Name,Population FROM City WHERE Name='berlin';
+----+-------------+-------+------------+------+---------------+------+---------+-------+------+----------+-------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
+----+-------------+-------+------------+------+---------------+------+---------+-------+------+----------+-------+
| 1 | SIMPLE | City | NULL | ref | Name | Name | 106 | const | 1 | 100.00 | NULL |
+----+-------------+-------+------------+------+---------------+------+---------+-------+------+----------+-------+
1 row in set, 1 warning (0,00 sec)
Very efficient statement, using the index. But unfortunately it did not find the row as the search is based on the case sensitive collation.
Now let's change the collation for the WHERE clause:
mysql> SELECT Name,Population FROM City WHERE Name='berlin' COLLATE utf8_general_ci;
+--------+------------+
| Name | Population |
+--------+------------+
| Berlin | 3386667 |
+--------+------------+
1 row in set (0,00 sec)
mysql> EXPLAIN SELECT Name,Population FROM City WHERE Name='berlin' COLLATE utf8_general_ci;
+----+-------------+-------+------------+------+---------------+------+---------+------+------+----------+-------------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
+----+-------------+-------+------------+------+---------------+------+---------+------+------+----------+-------------+
| 1 | SIMPLE | City | NULL | ALL | Name | NULL | NULL | NULL | 4108 | 10.00 | Using where |
+----+-------------+-------+------------+------+---------------+------+---------+------+------+----------+-------------+
1 row in set, 3 warnings (0,00 sec)
The result is what we wanted but the query creates a full table scan. Not good. BTW: The warnings point you to the fact that the index could not be used.
The solution
Now let's see how
auto generated columns in the new
MySQL 5.7 Development Milestone Release can help us. First let's create a copy of the Name column but with a different collation:
mysql> ALTER TABLE City ADD COLUMN Name_ci char(35) CHARACTER SET utf8 AS (Name) STORED;
Query OK, 4079 rows affected (0,50 sec)
Records: 4079 Duplicates: 0 Warnings: 0
"
AS (Name) STORED" is the new stuff: In the brackets is the expression to calculate the column value. Here it is a simple copy of the Name column. The keyword
STORED means that the data is physically stored and not calculated on the fly. This is necessary to create the index now:
mysql> ALTER TABLE City ADD INDEX (Name_ci);
Query OK, 0 rows affected (0,13 sec)
Records: 0 Duplicates: 0 Warnings: 0
As utf8_general_ci is the default collation with utf8, there is no need to specify this with the new column. Now let's see how to search:
mysql> SELECT Name, Population FROM City WHERE Name_ci='berlin';
+--------+------------+
| Name | Population |
+--------+------------+
| Berlin | 3386667 |
+--------+------------+
1 row in set (0,00 sec)
mysql> EXPLAIN SELECT Name, Population FROM City WHERE Name_ci='berlin';nbsp;
+----+-------------+-------+------------+------+---------------+---------+---------+-------+------+----------+-------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
+----+-------------+-------+------------+------+---------------+---------+---------+-------+------+----------+-------+
| 1 | SIMPLE | City | NULL | ref | Name_ci | Name_ci | 106 | const | 1 | 100.00 | NULL |
+----+-------------+-------+------------+------+---------------+---------+---------+-------+------+----------+-------+
1 row in set, 1 warning (0,00 sec)
Now we can search case sensitive (...WHERE Name=...) and case insensitive (WHERE Name_ci=...) and leverage indexes in both cases.
tl;dr
Use auto generated columns in MySQL 5.7 to create an additional index with a different collation. Now you can search based on different indexes.