表做了分析和优化:
ANALYZE TABLE Currsession_table;
OPTIMIZE TABLE Currsession_table;
两种写法严重的性能差异:

原因rcdate字段类型为datetime


下面的写法多了.0000毫秒信息,导致类型不同比较没有走索引。
select貌似走了索引,但rows显示还是全表的数据180多万,明显不正常。
delete完全没有走索引。
更换写法后可以看到,如果正常走索引应该就1条记录。


root@192.168.1.51 [jyc] >explain select count(*) FROM Currsession_table FORCE INDEX(idx_recdate) WHERE recdate < DATE_ADD(SYSDATE(), INTERVAL - (1500/86400) * 86400 SECOND);
+----+-------------+-------------------+------------+-------+---------------+-------------+---------+------+---------+----------+--------------------------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
+----+-------------+-------------------+------------+-------+---------------+-------------+---------+------+---------+----------+--------------------------+
| 1 | SIMPLE | Currsession_table | NULL | index | NULL | idx_recdate | 6 | NULL | 1823021 | 33.33 | Using where; Using index |
+----+-------------+-------------------+------------+-------+---------------+-------------+---------+------+---------+----------+--------------------------+
1 row in set, 1 warning (0.01 sec)
root@192.168.1.51 [jyc] >explain select count(*) FROM Currsession_table use INDEX(idx_recdate) WHERE recdate < DATE_ADD(SYSDATE(), INTERVAL - (1500/86400) * 86400 SECOND);
+----+-------------+-------------------+------------+-------+---------------+-------------+---------+------+---------+----------+--------------------------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
+----+-------------+-------------------+------------+-------+---------------+-------------+---------+------+---------+----------+--------------------------+
| 1 | SIMPLE | Currsession_table | NULL | index | NULL | idx_recdate | 6 | NULL | 1776171 | 33.33 | Using where; Using index |
+----+-------------+-------------------+------------+-------+---------------+-------------+---------+------+---------+----------+--------------------------+
1 row in set, 1 warning (0.00 sec)
root@192.168.1.51 [jyc] >explain delete FROM Currsession_table use INDEX(idx_recdate) WHERE recdate < DATE_ADD(SYSDATE(), INTERVAL - (1500/86400) * 86400 SECOND);
ERROR 1064 (42000): You have an error in your SQL syntax; check the manual that corresponds to your MySQL server version for the right syntax to use near 'use INDEX(idx_recdate) WHERE recdate < DATE_ADD(SYSDATE(), INTERVAL - (1500/8640' at line 1
root@192.168.1.51 [jyc] >explain delete FROM Currsession_table WHERE recdate < DATE_ADD(SYSDATE(), INTERVAL - (1500/86400) * 86400 SECOND);
+----+-------------+-------------------+------------+------+---------------+------+---------+------+---------+----------+-------------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
+----+-------------+-------------------+------------+------+---------------+------+---------+------+---------+----------+-------------+
| 1 | DELETE | Currsession_table | NULL | ALL | NULL | NULL | NULL | NULL | 1773948 | 100.00 | Using where |
+----+-------------+-------------------+------------+------+---------------+------+---------+------+---------+----------+-------------+
1 row in set, 1 warning (0.00 sec)
root@192.168.1.51 [jyc] >select count(*) FROM Currsession_table use INDEX(idx_recdate) WHERE recdate < DATE_ADD(SYSDATE(), INTERVAL - (1500/86400) * 86400 SECOND);
+----------+
| count(*) |
+----------+
| 0 |
+----------+
1 row in set (6.71 sec)
root@192.168.1.51 [jyc] >select count(*) FROM Currsession_table WHERE recdate < DATE_ADD(SYSDATE(), INTERVAL - (1500/86400) * 86400 SECOND);
+----------+
| count(*) |
+----------+
| 0 |
+----------+
1 row in set (6.86 sec)
root@192.168.1.51 [jyc] >explain select count(*) FROM Currsession_table use INDEX(idx_recdate) WHERE recdate < DATE_ADD(SYSDATE(), INTERVAL - (1500/86400) * 86400 SECOND);
+----+-------------+-------------------+------------+-------+---------------+-------------+---------+------+---------+----------+--------------------------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
+----+-------------+-------------------+------------+-------+---------------+-------------+---------+------+---------+----------+--------------------------+
| 1 | SIMPLE | Currsession_table | NULL | index | NULL | idx_recdate | 6 | NULL | 1787580 | 33.33 | Using where; Using index |
+----+-------------+-------------------+------------+-------+---------------+-------------+---------+------+---------+----------+--------------------------+
1 row in set, 1 warning (0.00 sec)
root@192.168.1.51 [jyc] >explain delete FROM Currsession_table WHERE recdate <now() -interval 25 minute;
+----+-------------+-------------------+------------+-------+---------------+-------------+---------+-------+------+----------+-------------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
+----+-------------+-------------------+------------+-------+---------------+-------------+---------+-------+------+----------+-------------+
| 1 | DELETE | Currsession_table | NULL | range | idx_recdate | idx_recdate | 6 | const | 1 | 100.00 | Using where |
+----+-------------+-------------------+------------+-------+---------------+-------------+---------+-------+------+----------+-------------+
1 row in set, 1 warning (0.00 sec)
root@192.168.1.51 [jyc] >explain select count(*) FROM Currsession_table WHERE recdate <now() -interval 25 minute;
+----+-------------+-------------------+------------+-------+---------------+-------------+---------+------+------+----------+--------------------------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
+----+-------------+-------------------+------------+-------+---------------+-------------+---------+------+------+----------+--------------------------+
| 1 | SIMPLE | Currsession_table | NULL | range | idx_recdate | idx_recdate | 6 | NULL | 1 | 100.00 | Using where; Using index |
+----+-------------+-------------------+------------+-------+---------------+-------------+---------+------+------+----------+--------------------------+
1 row in set, 1 warning (0.00 sec)
「喜欢这篇文章,您的关注和赞赏是给作者最好的鼓励」
关注作者
【版权声明】本文为墨天轮用户原创内容,转载时必须标注文章的来源(墨天轮),文章链接,文章作者等基本信息,否则作者和墨天轮有权追究责任。如果您发现墨天轮中有涉嫌抄袭或者侵权的内容,欢迎发送邮件至:contact@modb.pro进行举报,并提供相关证据,一经查实,墨天轮将立刻删除相关内容。




