Bug #72815 | UPDATE ... WHERE ... ORDER BY... always does a filesort even if not required | ||
---|---|---|---|
Submitted: | 30 May 2014 11:06 | Modified: | 30 May 2014 11:07 |
Reporter: | Umesh Shastry | Email Updates: | |
Status: | Verified | Impact on me: | |
Category: | MySQL Server: Optimizer | Severity: | S5 (Performance) |
Version: | 5.1, 5.5, 5.6, 5.7 | OS: | Any |
Assigned to: | CPU Architecture: | Any |
[30 May 2014 11:06]
Umesh Shastry
[30 May 2014 11:07]
MySQL Verification Team
// 5.6.20, 5.7.5, 5.5.38 - All versions affected when using Innodb ## MyISAM mysql> CREATE TABLE update_test (a INT AUTO_INCREMENT PRIMARY KEY, b INT, c INT, INDEX (b,c))engine=myisam; INSERT INTO update_test (b, c) VALUES (1, 1), (1, 2), (1,3), (2, 2), (2, 3), (2,4), (2, 5), (5, 5), (6,6), (7,7); Query OK, 0 rows affected (0.09 sec) mysql> INSERT INTO update_test (b, c) VALUES (1, 1), (1, 2), (1,3), (2, 2), (2, 3), (2,4), (2, 5), (5, 5), (6,6), (7,7); Query OK, 10 rows affected (0.00 sec) Records: 10 Duplicates: 0 Warnings: 0 mysql> mysql> -- no filesort mysql> SELECT * FROM update_test WHERE b = 1 ORDER BY c LIMIT 2; +---+------+------+ | a | b | c | +---+------+------+ | 1 | 1 | 1 | | 2 | 1 | 2 | +---+------+------+ 2 rows in set (0.00 sec) mysql> SHOW SESSION STATUS LIKE 'Sort%'; +-------------------+-------+ | Variable_name | Value | +-------------------+-------+ | Sort_merge_passes | 0 | | Sort_range | 0 | | Sort_rows | 0 | | Sort_scan | 0 | +-------------------+-------+ 4 rows in set (0.00 sec) mysql> mysql> -- does an unneeded filesort mysql> UPDATE update_test SET a = a + 10 WHERE b = 1 ORDER BY c LIMIT 2; Query OK, 2 rows affected (0.00 sec) Rows matched: 2 Changed: 2 Warnings: 0 mysql> SHOW SESSION STATUS LIKE 'Sort%'; +-------------------+-------+ | Variable_name | Value | +-------------------+-------+ | Sort_merge_passes | 0 | | Sort_range | 0 | | Sort_rows | 0 | | Sort_scan | 0 | +-------------------+-------+ 4 rows in set (0.00 sec) ## InnoDB mysql> CREATE TABLE update_test (a INT AUTO_INCREMENT PRIMARY KEY, b INT, c INT, INDEX (b,c))engine=innodb; Query OK, 0 rows affected (0.37 sec) mysql> INSERT INTO update_test (b, c) VALUES (1, 1), (1, 2), (1,3), (2, 2), (2, 3), (2,4), (2, 5), (5, 5), (6,6), (7,7); Query OK, 10 rows affected (0.06 sec) Records: 10 Duplicates: 0 Warnings: 0 mysql> mysql> -- no filesort mysql> SELECT * FROM update_test WHERE b = 1 ORDER BY c LIMIT 2; +---+------+------+ | a | b | c | +---+------+------+ | 1 | 1 | 1 | | 2 | 1 | 2 | +---+------+------+ 2 rows in set (0.00 sec) mysql> SHOW SESSION STATUS LIKE 'Sort%'; +-------------------+-------+ | Variable_name | Value | +-------------------+-------+ | Sort_merge_passes | 0 | | Sort_range | 0 | | Sort_rows | 0 | | Sort_scan | 0 | +-------------------+-------+ 4 rows in set (0.00 sec) mysql> mysql> -- does an unneeded filesort mysql> UPDATE update_test SET a = a + 10 WHERE b = 1 ORDER BY c LIMIT 2; Query OK, 2 rows affected (0.04 sec) Rows matched: 2 Changed: 2 Warnings: 0 mysql> SHOW SESSION STATUS LIKE 'Sort%'; +-------------------+-------+ | Variable_name | Value | +-------------------+-------+ | Sort_merge_passes | 0 | | Sort_range | 1 | | Sort_rows | 2 | | Sort_scan | 0 | +-------------------+-------+ 4 rows in set (0.00 sec)