前言 開心一刻 兒子有道題不會做,喊我過去教他。我推了推一旁的老公:我頭疼,你去吧。老公不動,我:零花錢漲一千。話音剛落,老公就屁顛屁顛跑去兒子房間。進去不到幾分鐘,一聲怒吼伴隨著兒子的哭聲傳來的瞬間,老公從兒子房間出來,邊走邊說:“朽木不可雕也。”兒子從房間探出半個身子,一臉委屈:“爸爸也不會做, ...
前言
開心一刻
兒子有道題不會做,喊我過去教他。我推了推一旁的老公:我頭疼,你去吧。老公不動,我:零花錢漲一千。話音剛落,老公就屁顛屁顛跑去兒子房間。進去不到幾分鐘,一聲怒吼伴隨著兒子的哭聲傳來的瞬間,老公從兒子房間出來,邊走邊說:“朽木不可雕也。”兒子從房間探出半個身子,一臉委屈:“爸爸也不會做,他說給我一塊錢,讓我明天早點去學校抄同學的。還讓我不要告訴你,我不肯,他就吼我。”
問題背景
前段時間,被緊急調到一個新項目,支撐新項目的開發。跌跌撞撞之下,項目也正常上線了,期間收穫頗多,無論是業務上的,還是業務之外的。業務上的就不多說了,不具通用性,意義不大,有一點業務之外的東東給我的感觸比較深,特記錄下來,與大家分享下 : 查詢優化
查詢優化
完整示例工程:data-init,包括資料庫表的 ddl 和 dml,以及數據批量的生成
相關表
涉及的表不多,一共三張:額度表、記錄表 、 存款表
額度表 t_custmor_credit
CREATE TABLE t_customer_credit ( id INT(11) UNSIGNED NOT NULL AUTO_INCREMENT COMMENT '自增主鍵', login_name VARCHAR(50) NOT NULL COMMENT '名稱', credit_type TINYINT(1) NOT NULL COMMENT '額度類型,1:自由資金,2:凍結資金,3:優惠', amount DECIMAL(22,6) NOT NULL DEFAULT '0.00000' COMMENT '額度值', create_by VARCHAR(50) NOT NULL COMMENT '創建者', create_time DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '創建時間', update_time DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '創建時間', update_by VARCHAR(50) NOT NULL COMMENT '修改者', PRIMARY KEY (id) );View Code
記錄每個顧客的當前額度,額度一共分三種:自由資金、凍結資金和優惠,也就是說每個顧客會有 3 條記錄來表示他的各個額度。表中數據如下
額度記錄 t_custmor_credit_record
CREATE TABLE t_customer_credit_record ( id INT(11) UNSIGNED NOT NULL AUTO_INCREMENT COMMENT '自增主鍵', login_name VARCHAR(50) NOT NULL COMMENT '名稱', credit_type TINYINT(1) NOT NULL COMMENT '額度類型,參考t_custmor_credit的credit_type', bill_no VARCHAR(50) NOT NULL COMMENT '訂單號', amount_before DECIMAL(22,6) NOT NULL DEFAULT '0.00000' COMMENT '前額度值', amount_change DECIMAL(22,6) NOT NULL DEFAULT '0.00000' COMMENT '額度變化值', amount_after DECIMAL(22,6) NOT NULL DEFAULT '0.00000' COMMENT '後額度值', create_by VARCHAR(50) NOT NULL COMMENT '創建者', create_time DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '創建時間', remark VARCHAR(500) NOT NULL DEFAULT '' COMMENT '備註', PRIMARY KEY (id) );View Code
記錄顧客額度的每一次變化,只要有額度變化(不管是哪個額度進行了變化),都會新增3條記錄,每個類型的額度都會新增一條記錄。另外,該表只會有數據的插入,不會有數據的刪、改。表中數據如下
存款表 t_custmor_deposit
CREATE TABLE t_customer_deposit ( id INT(11) UNSIGNED NOT NULL AUTO_INCREMENT COMMENT '自增主鍵', login_name VARCHAR(50) NOT NULL COMMENT '名稱', bill_no VARCHAR(50) NOT NULL COMMENT '訂單號', amount DECIMAL(22,6) NOT NULL DEFAULT '0.00000' COMMENT '存款金額', deposit_state TINYINT(1) NOT NULL COMMENT '存款狀態: 1成功,2失敗,3未知', channal TINYINT(2) NOT NULL COMMENT '存款渠道: 1:銀聯,2支付寶,3微信', create_by VARCHAR(50) NOT NULL COMMENT '創建者', create_time DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '創建時間', remark VARCHAR(500) NOT NULL DEFAULT '' COMMENT '備註', PRIMARY KEY (id) );View Code
記錄顧客的每一次存款,該表只會有數據的插入,不會有數據的刪、改。表中數據如下
產品需求
分頁展示如下列表(具體的過濾條件就不列了,我們就當是初始狀態,還未輸入過濾條件)
實現比較簡單,t_custmor_credit_record 左關聯 t_custmor_deposit 就好,但是我們的額度記錄表與需求列表有些許的出入,需要做一下簡單的行轉列。
需求實現
我們先來看看最初的SQL查詢,這可能是很多人最容易想到的
SELECT MIN(tcd.channal) channal, MAX(tccr.id) mId,tccr.login_name,tccr.bill_no,tccr.create_time, IF(credit_type=1,amount_before,0) AS freeBefore, IF(credit_type=1,amount_change,0) AS freeChange, IF(credit_type=1,amount_after,0) AS freeAfter, IF(credit_type=2,amount_before,0) AS freezeBefore, IF(credit_type=2,amount_change,0) AS freezeChange, IF(credit_type=2,amount_after,0) AS freezeAfter, IF(credit_type=3,amount_before,0) AS promotionBefore, IF(credit_type=3,amount_change,0) AS promotionChange, IF(credit_type=3,amount_after,0) AS promotionAfter FROM t_customer_credit_record tccr LEFT JOIN t_customer_deposit tcd ON tccr.bill_no = tcd.bill_no GROUP BY tccr.bill_no,tccr.login_name,tccr.create_time ORDER BY mId desc LIMIT 0, 10;View Code
數據量少的時候,也許能在我們接受的時間內查出我們需要的結果,一旦數據量多了,這個SQL就跑不動了;我們先看下 60w 數據的情況下,我們只進行 t_custmor_credit_record 單表查詢
SELECT MAX(id) mId,login_name,bill_no,create_time, IF(credit_type=1,amount_before,0) AS freeBefore, IF(credit_type=1,amount_change,0) AS freeChange, IF(credit_type=1,amount_after,0) AS freeAfter, IF(credit_type=2,amount_before,0) AS freezeBefore, IF(credit_type=2,amount_change,0) AS freezeChange, IF(credit_type=2,amount_after,0) AS freezeAfter, IF(credit_type=3,amount_before,0) AS promotionBefore, IF(credit_type=3,amount_change,0) AS promotionChange, IF(credit_type=3,amount_after,0) AS promotionAfter FROM t_customer_credit_record GROUP BY bill_no,login_name,create_time ORDER BY mId desc LIMIT 0, 10;View Code
效果如下
花了近 8 秒,這還只是單表,如果執行上面的聯表SQL,那時間又得增加不少(我試驗的結果是直接卡住了,看不到查詢結果);
優化處理
加索引
查詢慢的時候,我們最容易想到的優化方式往往就是加索引;上述SQL執行的時候,t_custmor_credit_record 和 t_custmor_deposit都沒有建索引(主鍵索引除外),那麼我們就加索引唄。我的項目中加的是唯一索引,做了唯一約束,那我這裡也加唯一索引
ALTER TABLE t_customer_credit_record ADD UNIQUE uk_unique (bill_no,login_name,create_time,credit_type); ALTER TABLE t_customer_deposit ADD UNIQUE uk_billno (bill_no);
此時我們看下SQL執行效果
我們發現,t_custmor_credit_record 單表查詢的效率幾乎沒變,將近 8 秒,但 t_custmor_credit_record 與 t_custmor_deposit 聯表的查詢卻在 11 秒內有結果了。加了索引為什麼還這麼慢了? 難道沒走索引?
我們是不是發現了什麼? IF函數對聯表查詢是否走索引有影響,也對單表的查詢速度有影響。上圖中的 t_custmor_credit_record 單表查詢,有IF函數,查詢時間近 8 秒,沒有IF函數,查詢時間 2 秒左右;t_custmor_credit_record 與 t_custmor_deposit 聯表查,有IF函數,t_custmor_credit_record 走的是全表查,查詢時間近 11 秒,沒有IF函數,t_custmor_credit_record 走的是索引,查詢時間 3 秒不到。那麼我們有沒有什麼辦法拿掉這個IF函數呢?
使用 CASE...WHEN....THEN 代替 IF
SELECT MAX(id) mId,login_name,bill_no,create_time, CASE credit_type WHEN 1 THEN amount_before ELSE 0 END AS freeBefore, CASE credit_type WHEN 1 THEN amount_change ELSE 0 END AS freeChange, CASE credit_type WHEN 1 THEN amount_after ELSE 0 END AS freeAfter, CASE credit_type WHEN 2 THEN amount_before ELSE 0 END AS freeChange, CASE credit_type WHEN 2 THEN amount_change ELSE 0 END AS freeChange, CASE credit_type WHEN 2 THEN amount_after ELSE 0 END AS freeChange, CASE credit_type WHEN 3 THEN amount_before ELSE 0 END AS promotionBefore, CASE credit_type WHEN 3 THEN amount_change ELSE 0 END AS promotionChange, CASE credit_type WHEN 3 THEN amount_after ELSE 0 END AS promotionAfter FROM t_customer_credit_record GROUP BY bill_no,login_name,create_time ORDER BY mId desc LIMIT 0, 10; SELECT MIN(tcd.channal) channal, MAX(tccr.id) mId,tccr.login_name,tccr.bill_no,tccr.create_time, CASE credit_type WHEN 1 THEN amount_before ELSE 0 END AS freeBefore, CASE credit_type WHEN 1 THEN amount_change ELSE 0 END AS freeChange, CASE credit_type WHEN 1 THEN amount_after ELSE 0 END AS freeAfter, CASE credit_type WHEN 2 THEN amount_before ELSE 0 END AS freeChange, CASE credit_type WHEN 2 THEN amount_change ELSE 0 END AS freeChange, CASE credit_type WHEN 2 THEN amount_after ELSE 0 END AS freeChange, CASE credit_type WHEN 3 THEN amount_before ELSE 0 END AS promotionBefore, CASE credit_type WHEN 3 THEN amount_change ELSE 0 END AS promotionChange, CASE credit_type WHEN 3 THEN amount_after ELSE 0 END AS promotionAfter FROM t_customer_credit_record tccr LEFT JOIN t_customer_deposit tcd ON tccr.bill_no = tcd.bill_no GROUP BY tccr.bill_no,tccr.login_name,tccr.create_time ORDER BY mId desc LIMIT 0, 10;View Code
我們可以看到,執行時間與 IF 所差無幾,執行計劃也是與 IF 的一致,這也就反映出不是 IF的問題,應該是 GROUP BY 的問題。我們用 GROUP BY 結合 IF(或 CASE...WHEN....THEN),就是為了將 3 條額度記錄合併成一條、行轉列之後輸出我們想要的結果,那有沒有不用 GROUP BY、又能實現我們需求的方式了?
自聯代替 GROUP BY
我們再仔細琢磨下這個需求,咋一看,確實需要行轉列,那麼就需要用到 GROUP BY,那麼效率也就低了,這似乎是無解了? 真的非要行轉列嗎,假設我們將額度記錄拆分成 3 張表:一張表只存自由資金的額度變化、一張表只存凍結資金的額度變化、一張表只存優惠的額度變化,這樣是不是只需要聯表查而不要用 GROUP BY 來進行行轉列了? 有小伙伴有可能會問:t_custmor_credit_record 表已經定了,數據都跑了不少了,再將其進行拆分,既要改表(同時還要遷移數據),還要改代碼,工程量會很大! 我們換個角度來看 t_custmor_credit_record ,目前它是 3 中額度記錄的一個總和表,我們能不能從它的身上做文章,變化出我們想要的那 3 張表,然後進行聯表查詢呢? 肯定可以的,類似如下
-- 自由資金額度記錄表 SELECT * FROM t_customer_credit_record WHERE credit_type = 1; -- 凍結資金額度記錄表 SELECT * FROM t_customer_credit_record WHERE credit_type = 2; -- 優惠額度記錄表 SELECT * FROM t_customer_credit_record WHERE credit_type = 3;
接下來的 SQL 怎麼寫,我想大家都知道了吧,自聯就行了,寫法有很多種,常見的寫法有如下 4 種
-- 不用group by,做法1, 個人比較推薦, 但此種方式不支持存款表的過濾條件 SELECT d.channal,a.amount_before AS freeBefore,a.amount_change AS freeChange, a.amount_after freeAfter, b.amount_before AS freezeBefore,b.amount_change AS freezeChange, b.amount_after freezeAfter, c.amount_before AS promotionBefore,c.amount_change AS promotionChange, c.amount_after promotionAfter FROM ( SELECT * FROM t_customer_credit_record WHERE credit_type = 1 ORDER BY id DESC LIMIT 0, 10 ) a LEFT JOIN t_customer_credit_record b ON a.bill_no = b.bill_no AND b.credit_type = 2 LEFT JOIN t_customer_credit_record c ON a.bill_no = c.bill_no AND c.credit_type = 3 LEFT JOIN t_customer_deposit d ON a.bill_no = d.bill_no; -- 不用group by,做法2, 此種方式支持存款表的過濾條件 SELECT a.channal,a.amount_before AS freeBefore,a.amount_change AS freeChange, a.amount_after freeAfter, b.amount_before AS freezeBefore,b.amount_change AS freezeChange, b.amount_after freezeAfter, c.amount_before AS promotionBefore,c.amount_change AS promotionChange, c.amount_after promotionAfter FROM ( SELECT r.*,d.channal FROM t_customer_credit_record r LEFT JOIN t_customer_deposit d ON r.bill_no = d.bill_no WHERE r.credit_type = 1 ORDER BY r.id DESC LIMIT 0, 10 ) a LEFT JOIN t_customer_credit_record b ON a.bill_no = b.bill_no AND b.credit_type = 2 LEFT JOIN t_customer_credit_record c ON a.bill_no = c.bill_no AND c.credit_type = 3; -- 不用group by,做法3, 這是最容易想到的方法 SELECT d.channal,a.amount_before AS freeBefore,a.amount_change AS freeChange, a.amount_after freeAfter, b.amount_before AS freezeBefore,b.amount_change AS freezeChange, b.amount_after freezeAfter, c.amount_before AS promotionBefore,c.amount_change AS promotionChange, c.amount_after promotionAfter FROM t_customer_credit_record a LEFT JOIN t_customer_credit_record b ON a.bill_no = b.bill_no LEFT JOIN t_customer_credit_record c ON a.bill_no = c.bill_no LEFT JOIN t_customer_deposit d ON a.bill_no = d.bill_no WHERE a.credit_type = 1 AND b.credit_type = 2 AND c.credit_type = 3 ORDER BY a.id DESC LIMIT 0, 10; -- 不用group by,做法4 SELECT d.channal,a.amount_before AS freeBefore,a.amount_change AS freeChange, a.amount_after freeAfter, b.amount_before AS freezeBefore,b.amount_change AS freezeChange, b.amount_after freezeAfter, c.amount_before AS promotionBefore,c.amount_change AS promotionChange, c.amount_after promotionAfter FROM t_customer_credit_record a LEFT JOIN t_customer_credit_record b ON a.bill_no = b.bill_no AND b.credit_type = 2 LEFT JOIN t_customer_credit_record c ON a.bill_no = c.bill_no AND c.credit_type = 3 LEFT JOIN t_customer_deposit d ON a.bill_no = d.bill_no WHERE a.credit_type = 1 ORDER BY a.id DESC LIMIT 0, 10;View Code
執行結果如下
就目前的數據量而言,4 種寫法的效率一樣,但是數據量再往上走,它們之前還是有性能差別的,大家可以仔細看看這 4 個 SQL 的執行計劃,它們之間還是有區別的。最終我的項目中採用的是第一種寫法
表重新設計
我們回過頭去看看 t_customer_credit 和 t_custmor_credit_record,是否真的有必要用 3 條記錄來存放顧客的 3 種額度,一條記錄將用戶的 3 種額度都記錄下來不是更好嗎? 如下所示
-- 自認為更好的表設計 DROP TABLE IF EXISTS t_customer_credit_plus; CREATE TABLE t_customer_credit_plus ( id INT(11) UNSIGNED NOT NULL AUTO_INCREMENT COMMENT '自增主鍵', login_name VARCHAR(50) NOT NULL COMMENT '登錄名', free_amount DECIMAL(22,6) NOT NULL DEFAULT '0.00000' COMMENT '自由資金額度', freeze_amount DECIMAL(22,6) NOT NULL DEFAULT '0.00000' COMMENT '凍結資金額度', promotion_amount DECIMAL(22,6) NOT NULL DEFAULT '0.00000' COMMENT '優惠資金額度', create_by VARCHAR(50) NOT NULL COMMENT '創建者', create_time DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '創建時間', update_time DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '創建時間', update_by VARCHAR(50) NOT NULL COMMENT '修改者', PRIMARY KEY (id), UNIQUE KEY `uk_login_name` (`login_name`) ); DROP TABLE IF EXISTS t_customer_credit_record_plus; CREATE TABLE t_customer_credit_record_plus ( id INT(11) UNSIGNED NOT NULL AUTO_INCREMENT COMMENT '自增主鍵', login_name VARCHAR(50) NOT NULL COMMENT '登錄名', bill_no VARCHAR(50) NOT NULL COMMENT '訂單號', free_amount_before DECIMAL(22,6) NOT NULL DEFAULT '0.00000' COMMENT '自由資金前額度值', free_amount_change DECIMAL(22,6) NOT NULL DEFAULT '0.00000' COMMENT '自由資金前額度變化值', free_amount_after DECIMAL(22,6) NOT NULL DEFAULT '0.00000' COMMENT '自由資金前後額度值', freeze_amount_before DECIMAL(22,6) NOT NULL DEFAULT '0.00000' COMMENT '凍結資金前額度值', freeze_amount_change DECIMAL(22,6) NOT NULL DEFAULT '0.00000' COMMENT