面試官:一千萬(wàn)數(shù)據(jù),怎么快速查詢?
也許有些人沒(méi)遇過(guò)上千萬(wàn)數(shù)據(jù)量的表,也不清楚查詢上千萬(wàn)數(shù)據(jù)量的時(shí)候會(huì)發(fā)生什么。
今天就來(lái)帶大家實(shí)操一下,這次是基于MySQL 5.7.26做測(cè)試
準(zhǔn)備數(shù)據(jù)
沒(méi)有一千萬(wàn)的數(shù)據(jù)怎么辦?
創(chuàng)建唄
代碼創(chuàng)建一千萬(wàn)?那是不可能的,太慢了,可能真的要跑一天??梢圆捎脭?shù)據(jù)庫(kù)腳本執(zhí)行速度快很多。
創(chuàng)建表
CREATE TABLE `user_operation_log` (
`id` int(11) NOT NULL AUTO_INCREMENT,
`user_id` varchar(64) CHARACTER SET utf8mb4 COLLATE utf8mb4_general_ci NULL DEFAULT NULL,
`ip` varchar(20) CHARACTER SET utf8mb4 COLLATE utf8mb4_general_ci NULL DEFAULT NULL,
`op_data` varchar(255) CHARACTER SET utf8mb4 COLLATE utf8mb4_general_ci NULL DEFAULT NULL,
`attr1` varchar(255) CHARACTER SET utf8mb4 COLLATE utf8mb4_general_ci NULL DEFAULT NULL,
`attr2` varchar(255) CHARACTER SET utf8mb4 COLLATE utf8mb4_general_ci NULL DEFAULT NULL,
`attr3` varchar(255) CHARACTER SET utf8mb4 COLLATE utf8mb4_general_ci NULL DEFAULT NULL,
`attr4` varchar(255) CHARACTER SET utf8mb4 COLLATE utf8mb4_general_ci NULL DEFAULT NULL,
`attr5` varchar(255) CHARACTER SET utf8mb4 COLLATE utf8mb4_general_ci NULL DEFAULT NULL,
`attr6` varchar(255) CHARACTER SET utf8mb4 COLLATE utf8mb4_general_ci NULL DEFAULT NULL,
`attr7` varchar(255) CHARACTER SET utf8mb4 COLLATE utf8mb4_general_ci NULL DEFAULT NULL,
`attr8` varchar(255) CHARACTER SET utf8mb4 COLLATE utf8mb4_general_ci NULL DEFAULT NULL,
`attr9` varchar(255) CHARACTER SET utf8mb4 COLLATE utf8mb4_general_ci NULL DEFAULT NULL,
`attr10` varchar(255) CHARACTER SET utf8mb4 COLLATE utf8mb4_general_ci NULL DEFAULT NULL,
`attr11` varchar(255) CHARACTER SET utf8mb4 COLLATE utf8mb4_general_ci NULL DEFAULT NULL,
`attr12` varchar(255) CHARACTER SET utf8mb4 COLLATE utf8mb4_general_ci NULL DEFAULT NULL,
PRIMARY KEY (`id`) USING BTREE
) ENGINE = InnoDB AUTO_INCREMENT = 1 CHARACTER SET = utf8mb4 COLLATE = utf8mb4_general_ci ROW_FORMAT = Dynamic;
創(chuàng)建數(shù)據(jù)腳本
采用批量插入,效率會(huì)快很多,而且每1000條數(shù)就commit,數(shù)據(jù)量太大,也會(huì)導(dǎo)致批量插入效率慢
DELIMITER ;;
CREATE PROCEDURE batch_insert_log()
BEGIN
DECLARE i INT DEFAULT 1;
DECLARE userId INT DEFAULT 10000000;
set @execSql = 'INSERT INTO `test`.`user_operation_log`(`user_id`, `ip`, `op_data`, `attr1`, `attr2`, `attr3`, `attr4`, `attr5`, `attr6`, `attr7`, `attr8`, `attr9`, `attr10`, `attr11`, `attr12`) VALUES';
set @execData = '';
WHILE i<=10000000 DO
set @attr = "'測(cè)試很長(zhǎng)很長(zhǎng)很長(zhǎng)很長(zhǎng)很長(zhǎng)很長(zhǎng)很長(zhǎng)很長(zhǎng)很長(zhǎng)很長(zhǎng)很長(zhǎng)很長(zhǎng)很長(zhǎng)很長(zhǎng)很長(zhǎng)很長(zhǎng)很長(zhǎng)的屬性'";
set @execData = concat(@execData, "(", userId + i, ", '10.0.69.175', '用戶登錄操作'", ",", @attr, ",", @attr, ",", @attr, ",", @attr, ",", @attr, ",", @attr, ",", @attr, ",", @attr, ",", @attr, ",", @attr, ",", @attr, ",", @attr, ")");
if i % 1000 = 0
then
set @stmtSql = concat(@execSql, @execData,";");
prepare stmt from @stmtSql;
execute stmt;
DEALLOCATE prepare stmt;
commit;
set @execData = "";
else
set @execData = concat(@execData, ",");
end if;
SET i=i+1;
END WHILE;
END;;
DELIMITER ;
開(kāi)始測(cè)試
哥的電腦配置比較低:win10 標(biāo)壓渣渣i5 讀寫(xiě)約500MB的SSD
由于配置低,本次測(cè)試只準(zhǔn)備了3148000條數(shù)據(jù),占用了磁盤(pán)5G(還沒(méi)建索引的情況下),跑了38min,電腦配置好的同學(xué),可以插入多點(diǎn)數(shù)據(jù)測(cè)試
SELECT count(1) FROM `user_operation_log`
返回結(jié)果:3148000
三次查詢時(shí)間分別為:
14060 ms
13755 ms
13447 ms
普通分頁(yè)查詢
MySQL 支持 LIMIT 語(yǔ)句來(lái)選取指定的條數(shù)數(shù)據(jù), Oracle 可以使用 ROWNUM 來(lái)選取。
MySQL分頁(yè)查詢語(yǔ)法如下:
SELECT * FROM table LIMIT [offset,] rows | rows OFFSET offset
第一個(gè)參數(shù)指定第一個(gè)返回記錄行的偏移量
第二個(gè)參數(shù)指定返回記錄行的最大數(shù)目
下面我們開(kāi)始測(cè)試查詢結(jié)果:
SELECT * FROM `user_operation_log` LIMIT 10000, 10
查詢3次時(shí)間分別為:
59 ms
49 ms
50 ms
這樣看起來(lái)速度還行,不過(guò)是本地?cái)?shù)據(jù)庫(kù),速度自然快點(diǎn)。
換個(gè)角度來(lái)測(cè)試
相同偏移量,不同數(shù)據(jù)量
SELECT * FROM `user_operation_log` LIMIT 10000, 10
SELECT * FROM `user_operation_log` LIMIT 10000, 100
SELECT * FROM `user_operation_log` LIMIT 10000, 1000
SELECT * FROM `user_operation_log` LIMIT 10000, 10000
SELECT * FROM `user_operation_log` LIMIT 10000, 100000
SELECT * FROM `user_operation_log` LIMIT 10000, 1000000
查詢時(shí)間如下:
從上面結(jié)果可以得出結(jié)束:數(shù)據(jù)量越大,花費(fèi)時(shí)間越長(zhǎng)
相同數(shù)據(jù)量,不同偏移量
SELECT * FROM `user_operation_log` LIMIT 100, 100
SELECT * FROM `user_operation_log` LIMIT 1000, 100
SELECT * FROM `user_operation_log` LIMIT 10000, 100
SELECT * FROM `user_operation_log` LIMIT 100000, 100
SELECT * FROM `user_operation_log` LIMIT 1000000, 100
從上面結(jié)果可以得出結(jié)束:偏移量越大,花費(fèi)時(shí)間越長(zhǎng)
SELECT * FROM `user_operation_log` LIMIT 100, 100
SELECT id, attr FROM `user_operation_log` LIMIT 100, 100
如何優(yōu)化
既然我們經(jīng)過(guò)上面一番的折騰,也得出了結(jié)論,針對(duì)上面兩個(gè)問(wèn)題:偏移大、數(shù)據(jù)量大,我們分別著手優(yōu)化
優(yōu)化偏移量大問(wèn)題
采用子查詢方式
我們可以先定位偏移位置的 id,然后再查詢數(shù)據(jù)
SELECT * FROM `user_operation_log` LIMIT 1000000, 10SELECT id FROM `user_operation_log` LIMIT 1000000, 1SELECT * FROM `user_operation_log` WHERE id >= (SELECT id FROM `user_operation_log` LIMIT 1000000, 1) LIMIT 10
查詢結(jié)果如下:
從上面結(jié)果得出結(jié)論:
第一條花費(fèi)的時(shí)間最大,第三條比第一條稍微好點(diǎn)
子查詢使用索引速度更快
缺點(diǎn):只適用于id遞增的情況
id非遞增的情況可以使用以下寫(xiě)法,但這種缺點(diǎn)是分頁(yè)查詢只能放在子查詢里面
注意:某些 mysql 版本不支持在 in 子句中使用 limit,所以采用了多個(gè)嵌套select
SELECT * FROM `user_operation_log` WHERE id IN (SELECT t.id FROM (SELECT id FROM `user_operation_log` LIMIT 1000000, 10) AS t)
采用 id 限定方式
這種方法要求更高些,id必須是連續(xù)遞增,而且還得計(jì)算id的范圍,然后使用 between,sql如下
SELECT * FROM `user_operation_log` WHERE id between 1000000 AND 1000100 LIMIT 100
#公眾號(hào):碼農(nóng)編程進(jìn)階筆記
SELECT * FROM `user_operation_log` WHERE id >= 1000000 LIMIT 100
查詢結(jié)果如下:
從結(jié)果可以看出這種方式非???br>
注意:這里的 LIMIT 是限制了條數(shù),沒(méi)有采用偏移量
優(yōu)化數(shù)據(jù)量大問(wèn)題
返回結(jié)果的數(shù)據(jù)量也會(huì)直接影響速度
SELECT * FROM `user_operation_log` LIMIT 1, 1000000
SELECT id FROM `user_operation_log` LIMIT 1, 1000000
SELECT id, user_id, ip, op_data, attr1, attr2, attr3, attr4, attr5, attr6, attr7, attr8, attr9, attr10, attr11, attr12 FROM `user_operation_log` LIMIT 1, 1000000
查詢結(jié)果如下:
從結(jié)果可以看出減少不需要的列,查詢效率也可以得到明顯提升
第一條和第三條查詢速度差不多,這時(shí)候你肯定會(huì)吐槽,那我還寫(xiě)那么多字段干啥呢,直接 * 不就完事了
注意本人的 MySQL 服務(wù)器和客戶端是在_同一臺(tái)機(jī)器_上,所以查詢數(shù)據(jù)相差不多,有條件的同學(xué)可以測(cè)測(cè)客戶端與MySQL分開(kāi)
SELECT * 它不香嗎?
在這里順便補(bǔ)充一下為什么要禁止 SELECT *。難道簡(jiǎn)單無(wú)腦,它不香嗎?
主要兩點(diǎn):
用 "SELECT * " 數(shù)據(jù)庫(kù)需要解析更多的對(duì)象、字段、權(quán)限、屬性等相關(guān)內(nèi)容,在 SQL 語(yǔ)句復(fù)雜,硬解析較多的情況下,會(huì)對(duì)數(shù)據(jù)庫(kù)造成沉重的負(fù)擔(dān)。
增大網(wǎng)絡(luò)開(kāi)銷(xiāo),* 有時(shí)會(huì)誤帶上如log、IconMD5之類(lèi)的無(wú)用且大文本字段,數(shù)據(jù)傳輸size會(huì)幾何增漲。特別是MySQL和應(yīng)用程序不在同一臺(tái)機(jī)器,這種開(kāi)銷(xiāo)非常明顯。
結(jié)束
最后還是希望大家自己去實(shí)操一下,肯定還可以收獲更多,歡迎留言??!
作者:碼農(nóng)編程進(jìn)階筆記
歡迎關(guān)注微信公眾號(hào) :碼農(nóng)編程進(jìn)階筆記