问题背景
前段时间,被紧急调到一个新项目,支撑新项目的开发。跌跌撞撞之下,项目也正常上线了,期间收获颇多,无论是业务上的,还是业务之外的。业务上的就不多说了,不具通用性,意义不大,有一点业务之外的东东给我的感触比较深,特记录下来,与大家分享下 :查询优化查询优化
完整示例工程:data-init,包括数据库表的 ddl 和 dml,以及数据批量的生成相关表
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) );
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) );
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) );
产品需求
分页展示如下列表(具体的过滤条件就不列了,我们就当是初始状态,还未输入过滤条件)
实现比较简单,t_custmor_credit_record 左关联 t_custmor_deposit 就好,但是我们的额度记录表与需求列表有些许的出入,需要做一下简单的行转列。
需求实现
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;
数据量少的时候,也许能在我们接受的时间内查出我们需要的结果,一旦数据量多了,这个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;
效果如下
优化处理
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执行效果
我们是不是发现了什么?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函数呢?
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;
-- 自由资金额度记录表 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;
-- 不用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;
执行结果如下
就目前的数据量而言,4 种写法的效率一样,但是数据量再往上走,它们之前还是有性能差别的,大家可以仔细看看这 4 个 SQL 的执行计划,它们之间还是有区别的。最终我的项目中采用的是第一种写法
-- 自认为更好的表设计 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 '冻结资金额度变化值', freeze_amount_after DECIMAL(22,6) NOT NULL DEFAULT '0.00000' COMMENT '冻结资金后额度值', promotion_amount_before DECIMAL(22,6) NOT NULL DEFAULT '0.00000' COMMENT '优惠前额度值', promotion_amount_change DECIMAL(22,6) NOT NULL DEFAULT '0.00000' COMMENT '优惠额度变化值', promotion_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), UNIQUE KEY `uk_unique` (`bill_no`,`login_name`,`create_time`) );
总结
1、SQL 行转列,往往是 GROUP BY 配合聚合函数(SUM、MAX、MIN等)来实现,当然也包括 IF 和 CASE...WHEN....THEN;
扫码二维码 获取免费视频学习资料
- 本文固定链接: http://phpxs.com/post/6534/
- 转载请注明:转载必须在正文中标注并保留原文链接
- 扫码: 扫上方二维码获取免费视频资料