MySQL優(yōu)化案例系列 — RAND()優(yōu)化
眾所周知,在MySQL中,如果直接 ORDER BY RAND() 的話,效率非常差,因?yàn)闀?huì)多次執(zhí)行。事實(shí)上,如果等值查詢也是用 RAND() 的話也如此,我們先來看看下面這幾個(gè)SQL的不同執(zhí)行計(jì)劃和執(zhí)行耗時(shí)。
首先,看下建表DDL,這是一個(gè)沒有顯式自增主鍵的InnoDB表:
- [yejr@imysql]> show create table t_innodb_random\G
- *************************** 1. row ***************************
- Table: t_innodb_random
- Create Table: CREATE TABLE `t_innodb_random` (
- `id` int(10) unsigned NOT NULL,
- `user` varchar(64) NOT NULL DEFAULT '',
- KEY `idx_id` (`id`)
- ) ENGINE=InnoDB DEFAULT CHARSET=latin1
往這個(gè)表里灌入一些測(cè)試數(shù)據(jù),至少10萬以上, id 字段也是亂序的。
- [yejr@imysql]> select count(*) from t_innodb_random\G
- *************************** 1. row ***************************
- count(*): 393216
1、常量等值檢索:
- [yejr@imysql]> explain select id from t_innodb_random where id = 13412\G
- *************************** 1. row ***************************
- id: 1
- select_type: SIMPLE
- table: t_innodb_random
- type: ref
- possible_keys: idx_id
- key: idx_id
- key_len: 4
- ref: const
- rows: 1
- Extra: Using index
- [yejr@imysql]> select id from t_innodb_random where id = 13412;
- 1 row in set (0.00 sec)
可以看到執(zhí)行計(jì)劃很不錯(cuò),是常量等值查詢,速度非???。
2、使用RAND()函數(shù)乘以常量,求得隨機(jī)數(shù)后檢索:
- [yejr@imysql]> explain select id from t_innodb_random where id = round(rand()*13241324)\G
- *************************** 1. row ***************************
- id: 1
- select_type: SIMPLE
- table: t_innodb_random
- type: index
- possible_keys: NULL
- key: idx_id
- key_len: 4
- ref: NULL
- rows: 393345
- Extra: Using where; Using index
- [yejr@imysql]> select id from t_innodb_random where id = round(rand()*13241324)\G
- Empty set (0.26 sec)
可以看到執(zhí)行計(jì)劃很糟糕,雖然是只掃描索引,但是做了全索引掃描,效率非常差。因?yàn)閃HERE條件中包含了RAND(),使得MySQL把它當(dāng)做變量來處理,無法用常量等值的方式查詢,效率很低。
我們把常量改成取t_innodb_random表的***id值,再乘以RAND()求得隨機(jī)數(shù)后檢索看看什么情況:
- [yejr@imysql]> explain select id from t_innodb_random where id = round(rand()*(select max(id) from t_innodb_random))\G
- *************************** 1. row ***************************
- id: 1
- select_type: PRIMARY
- table: t_innodb_random
- type: index
- possible_keys: NULL
- key: idx_id
- key_len: 4
- ref: NULL
- rows: 393345
- Extra: Using where; Using index
- *************************** 2. row ***************************
- id: 2
- select_type: SUBQUERY
- table: NULL
- type: NULL
- possible_keys: NULL
- key: NULL
- key_len: NULL
- ref: NULL
- rows: NULL
- Extra: Select tables optimized away
- [yejr@imysql]> select id from t_innodb_random where id = round(rand()*(select max(id) from t_innodb_random))\G
- Empty set (0.27 sec)
可以看到,執(zhí)行計(jì)劃依然是全索引掃描,執(zhí)行耗時(shí)也基本相當(dāng)。
3、改造成普通子查詢模式 ,這里有兩次子查詢
- [yejr@imysql]> explain select id from t_innodb_random where id = (select round(rand()*(select max(id) from t_innodb_random)) as nid)\G
- *************************** 1. row ***************************
- id: 1
- select_type: PRIMARY
- table: t_innodb_random
- type: index
- possible_keys: NULL
- key: idx_id
- key_len: 4
- ref: NULL
- rows: 393345
- Extra: Using where; Using index
- *************************** 2. row ***************************
- id: 3
- select_type: SUBQUERY
- table: NULL
- type: NULL
- possible_keys: NULL
- key: NULL
- key_len: NULL
- ref: NULL
- rows: NULL
- Extra: Select tables optimized away
- [yejr@imysql]> select id from t_innodb_random where id = (select round(rand()*(select max(id) from t_innodb_random)) as nid)\G
- Empty set (0.27 sec)
可以看到,執(zhí)行計(jì)劃也不好,執(zhí)行耗時(shí)較慢。
4、改造成JOIN關(guān)聯(lián)查詢,不過***值還是用常量表示
- [yejr@imysql]> explain select id from t_innodb_random t1 join (select round(rand()*13241324) as id2) as t2 where t1.id = t2.id2\G
- *************************** 1. row ***************************
- id: 1
- select_type: PRIMARY
- table: <derived2>
- type: system
- possible_keys: NULL
- key: NULL
- key_len: NULL
- ref: NULL
- rows: 1
- Extra:
- *************************** 2. row ***************************
- id: 1
- select_type: PRIMARY
- table: t1
- type: ref
- possible_keys: idx_id
- key: idx_id
- key_len: 4
- ref: const
- rows: 1
- Extra: Using where; Using index
- *************************** 3. row ***************************
- id: 2
- select_type: DERIVED
- table: NULL
- type: NULL
- possible_keys: NULL
- key: NULL
- key_len: NULL
- ref: NULL
- rows: NULL
- Extra: No tables used
- [yejr@imysql]> select id from t_innodb_random t1 join (select round(rand()*13241324) as id2) as t2 where t1.id = t2.id2\G
- Empty set (0.00 sec)
這時(shí)候執(zhí)行計(jì)劃就非常***了,和最開始的常量等值查詢是一樣的了,執(zhí)行耗時(shí)也非常之快。
這種方法雖然很好,但是有可能查詢不到記錄,改造范圍查找,但結(jié)果LIMIT 1就可以了:
- [yejr@imysql]> explain select id from t_innodb_random where id > (select round(rand()*(select max(id) from t_innodb_random)) as nid) limit 1\G
- *************************** 1. row ***************************
- id: 1
- select_type: PRIMARY
- table: t_innodb_random
- type: index
- possible_keys: NULL
- key: idx_id
- key_len: 4
- ref: NULL
- rows: 393345
- Extra: Using where; Using index
- *************************** 2. row ***************************
- id: 3
- select_type: SUBQUERY
- table: NULL
- type: NULL
- possible_keys: NULL
- key: NULL
- key_len: NULL
- ref: NULL
- rows: NULL
- Extra: Select tables optimized away
- [yejr@imysql]> select id from t_innodb_random where id > (select round(rand()*(select max(id) from t_innodb_random)) as nid) limit 1\G
- *************************** 1. row ***************************
- id: 1301
- 1 row in set (0.00 sec)
可以看到,雖然執(zhí)行計(jì)劃也是全索引掃描,但是因?yàn)橛辛薒IMIT 1,只需要找到一條記錄,即可終止掃描,所以效率還是很快的。
小結(jié):
從數(shù)據(jù)庫中隨機(jī)取一條記錄時(shí),可以把RAND()生成隨機(jī)數(shù)放在JOIN子查詢中以提高效率。
5、再來看看用ORDRR BY RAND()方式一次取得多個(gè)隨機(jī)值的方式:
- [yejr@imysql]> explain select id from t_innodb_random order by rand() limit 1000\G
- *************************** 1. row ***************************
- id: 1
- select_type: SIMPLE
- table: t_innodb_random
- type: index
- possible_keys: NULL
- key: idx_id
- key_len: 4
- ref: NULL
- rows: 393345
- Extra: Using index; Using temporary; Using filesort
- [yejr@imysql]> select id from t_innodb_random order by rand() limit 1000;
- 1000 rows in set (0.41 sec)
全索引掃描,生成排序臨時(shí)表,太差太慢了。
6、把隨機(jī)數(shù)放在子查詢里看看:
- [yejr@imysql]> explain select id from t_innodb_random where id > (select rand() * (select max(id) from t_innodb_random) as nid) limit 1000\G
- *************************** 1. row ***************************
- id: 1
- select_type: PRIMARY
- table: t_innodb_random
- type: index
- possible_keys: NULL
- key: idx_id
- key_len: 4
- ref: NULL
- rows: 393345
- Extra: Using where; Using index
- *************************** 2. row ***************************
- id: 3
- select_type: SUBQUERY
- table: NULL
- type: NULL
- possible_keys: NULL
- key: NULL
- key_len: NULL
- ref: NULL
- rows: NULL
- Extra: Select tables optimized away
- [yejr@imysql]> select id from t_innodb_random where id > (select rand() * (select max(id) from t_innodb_random) as nid) limit 1000\G
- 1000 rows in set (0.04 sec)
嗯,提速了不少,這個(gè)看起來還不賴:)
7、仿照上面的方法,改成JOIN和隨機(jī)數(shù)子查詢關(guān)聯(lián)
- [yejr@imysql]> explain select id from t_innodb_random t1 join (select rand() * (select max(id) from t_innodb_random) as nid) t2 on t1.id > t2.nid limit 1000\G
- *************************** 1. row ***************************
- id: 1
- select_type: PRIMARY
- table: <derived2>
- type: system
- possible_keys: NULL
- key: NULL
- key_len: NULL
- ref: NULL
- rows: 1
- Extra:
- *************************** 2. row ***************************
- id: 1
- select_type: PRIMARY
- table: t1
- type: range
- possible_keys: idx_id
- key: idx_id
- key_len: 4
- ref: NULL
- rows: 196672
- Extra: Using where; Using index
- *************************** 3. row ***************************
- id: 2
- select_type: DERIVED
- table: NULL
- type: NULL
- possible_keys: NULL
- key: NULL
- key_len: NULL
- ref: NULL
- rows: NULL
- Extra: No tables used
- *************************** 4. row ***************************
- id: 3
- select_type: SUBQUERY
- table: NULL
- type: NULL
- possible_keys: NULL
- key: NULL
- key_len: NULL
- ref: NULL
- rows: NULL
- Extra: Select tables optimized away
- [yejr@imysql]> select id from t_innodb_random t1 join (select rand() * (select max(id) from t_innodb_random) as nid) t2 on t1.id > t2.nid limit 1000\G
- 1000 rows in set (0.00 sec)
可以看到,全索引檢索,發(fā)現(xiàn)符合記錄的條件后,直接取得1000行,這個(gè)方法是最快的。
綜上,想從MySQL數(shù)據(jù)庫中隨機(jī)取一條或者N條記錄時(shí),***把RAND()生成隨機(jī)數(shù)放在JOIN子查詢中以提高效率。
上面說了那么多的廢話,***簡(jiǎn)單說下,就是把下面這個(gè)SQL:
- SELECT id FROM table ORDER BY RAND() LIMIT n;
改造成下面這個(gè):
- SELECT id FROM table t1 JOIN (SELECT RAND() * (SELECT MAX(id) FROM table) AS nid) t2 ON t1.id > t2.nid LIMIT n;
如果想要達(dá)到完全隨機(jī),還可以改成下面這種寫法:
- SELECT id FROM table t1 JOIN (SELECT round(RAND() * (SELECT MAX(id) FROM table)) AS nid FROM table LIMIT n) t2 ON t1.id = t2.nid;
就可以享受在SQL中直接取得隨機(jī)數(shù)了,不用再在程序中構(gòu)造一串隨機(jī)數(shù)去檢索了。