ERROR 1193 (HY000) at line 38: Unknown system variable 'storage_engine'
连接mysql查看默认引擎,发现不是本地环境的问题。
1 2 3 4 5 6 7 8 9 10
mysql> show variables like '%engine%'; +----------------------------------+--------+ | Variable_name | Value | +----------------------------------+--------+ | default_storage_engine | InnoDB | | default_tmp_storage_engine | InnoDB | | disabled_storage_engines | | | internal_tmp_disk_storage_engine | InnoDB | +----------------------------------+--------+ 4 rows in set (0.01 sec)
修改 employees.sql 脚本
1 2 3 4 5 6 7
set default_storage_engine = InnoDB; -- set storage_engine = MyISAM; -- set storage_engine = Falcon; -- set storage_engine = PBXT; -- set storage_engine = Maria;
select CONCAT('storage engine: ', @@default_storage_engine) as INFO;
一般我们最常用的分页查询的方式为 order by + limit m,n 的方式, 现在我们测试下分页性能
1 2 3 4
select * from user order by score limit 0,10; -- 10 rows in set (0.65 sec) select * from user order by score limit 10000,10; -- 10 rows in set (0.83 sec) select * from user order by score limit 100000,10; -- 10 rows in set (1.03 sec) select * from user order by score limit 1000000,10; -- 10 rows in set (1.14 sec)
这里我们确认下是否用到了索引
1 2 3 4 5 6 7
mysql> explain select * from user order by score limit 1000000,10; +----+-------------+-------+------------+------+---------------+------+---------+------+---------+----------+----------------+ | id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra | +----+-------------+-------+------------+------+---------------+------+---------+------+---------+----------+----------------+ | 1 | SIMPLE | user | NULL | ALL | NULL | NULL | NULL | NULL | 2991995 | 100.00 | Using filesort | +----+-------------+-------+------------+------+---------------+------+---------+------+---------+----------+----------------+ 1 row in set, 1 warning (0.00 sec)
可以看到确实没有用到索引,全表扫描100W数据分页大概需要1.14s的时间。
3. 有索引分页查询
1 2 3
select * from user order by id limit 10000,10; -- 10 rows in set (0.01 sec) select * from user order by id limit 1000000,10; -- 10 rows in set (0.18 sec) select * from user order by id limit 2000000,10; -- 10 rows in set (0.35 sec)
该查询用到了主键索引,所以查询效率比较高。
可以看到,当数据量变大时,查询效率明显下降。
这里我们确认下是否使用到了索引
1 2 3 4 5 6 7
mysql> explain select * from user order by id limit 2000000,10; +----+-------------+-------+------------+-------+---------------+---------+---------+------+---------+----------+-------+ | id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra | +----+-------------+-------+------------+-------+---------------+---------+---------+------+---------+----------+-------+ | 1 | SIMPLE | user | NULL | index | NULL | PRIMARY | 4 | NULL | 2000010 | 100.00 | NULL | +----+-------------+-------+------------+-------+---------------+---------+---------+------+---------+----------+-------+ 1 row in set, 1 warning (0.00 sec)
mysql> select * from user where id > (select id from user order by id limit 2000000, 1) limit 10; +---------+--------------+---------+ | id | username | score | +---------+--------------+---------+ | 2000002 | user-2000002 | 2000002 | | 2000003 | user-2000003 | 2000003 | | 2000004 | user-2000004 | 2000004 | | 2000005 | user-2000005 | 2000005 | | 2000006 | user-2000006 | 2000006 | | 2000007 | user-2000007 | 2000007 | | 2000008 | user-2000008 | 2000008 | | 2000009 | user-2000009 | 2000009 | | 2000010 | user-2000010 | 2000010 | | 2000011 | user-2000011 | 2000011 | +---------+--------------+---------+ 10 rows in set (0.29 sec)
mysql> explain select * from user where id > (select id from user order by id limit 2000000, 1) limit 10; +----+-------------+-------+------------+-------+---------------+---------+---------+------+---------+----------+-------------+ | id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra | +----+-------------+-------+------------+-------+---------------+---------+---------+------+---------+----------+-------------+ | 1 | PRIMARY | user | NULL | range | PRIMARY | PRIMARY | 4 | NULL | 1495997 | 100.00 | Using where | | 2 | SUBQUERY | user | NULL | index | NULL | PRIMARY | 4 | NULL | 2000001 | 100.00 | Using index | +----+-------------+-------+------------+-------+---------------+---------+---------+------+---------+----------+-------------+ 2 rows in set, 1 warning (0.30 sec)