|
| 1 | +-- -------------------------------------------------------------------------------------- |
| 2 | +-- 函数操作影响索引效率示例 |
| 3 | +-- @author Zhang Peng |
| 4 | +-- ---------------------------------------------------------------------------------------- |
| 5 | + |
| 6 | +-- 步骤 1、建表 |
| 7 | +CREATE TABLE tradelog ( |
| 8 | + id INT(11) UNSIGNED NOT NULL AUTO_INCREMENT COMMENT 'Id', |
| 9 | + tradeid VARCHAR(32) DEFAULT NULL, |
| 10 | + operator INT(11) DEFAULT NULL, |
| 11 | + t_modified DATETIME DEFAULT NULL, |
| 12 | + PRIMARY KEY (id), |
| 13 | + KEY tradeid(tradeid), |
| 14 | + KEY t_modified(t_modified) |
| 15 | +) |
| 16 | + ENGINE = InnoDB |
| 17 | + DEFAULT CHARSET = utf8mb4; |
| 18 | + |
| 19 | +CREATE TABLE trade_detail ( |
| 20 | + id INT(11) NOT NULL, |
| 21 | + tradeid VARCHAR(32) DEFAULT NULL, |
| 22 | + trade_step INT(11) DEFAULT NULL, /* 操作步骤 */ |
| 23 | + step_info VARCHAR(32) DEFAULT NULL, /* 步骤信息 */ |
| 24 | + PRIMARY KEY (id), |
| 25 | + KEY tradeid(tradeid) |
| 26 | +) |
| 27 | + ENGINE = InnoDB |
| 28 | + DEFAULT CHARSET = utf8; |
| 29 | + |
| 30 | +-- 步骤 2、存储过程初始化数据 |
| 31 | + |
| 32 | +INSERT INTO trade_detail |
| 33 | +VALUES (1, 'aaaaaaaa', 1, 'add'); |
| 34 | +INSERT INTO trade_detail |
| 35 | +VALUES (2, 'aaaaaaaa', 2, 'update'); |
| 36 | +INSERT INTO trade_detail |
| 37 | +VALUES (3, 'aaaaaaaa', 3, 'commit'); |
| 38 | +INSERT INTO trade_detail |
| 39 | +VALUES (4, 'aaaaaaab', 1, 'add'); |
| 40 | +INSERT INTO trade_detail |
| 41 | +VALUES (5, 'aaaaaaab', 2, 'update'); |
| 42 | +INSERT INTO trade_detail |
| 43 | +VALUES (6, 'aaaaaaab', 3, 'update again'); |
| 44 | +INSERT INTO trade_detail |
| 45 | +VALUES (7, 'aaaaaaab', 4, 'commit'); |
| 46 | +INSERT INTO trade_detail |
| 47 | +VALUES (8, 'aaaaaaac', 1, 'add'); |
| 48 | +INSERT INTO trade_detail |
| 49 | +VALUES (9, 'aaaaaaac', 2, 'update'); |
| 50 | +INSERT INTO trade_detail |
| 51 | +VALUES (10, 'aaaaaaac', 3, 'update again'); |
| 52 | +INSERT INTO trade_detail |
| 53 | +VALUES (11, 'aaaaaaac', 4, 'commit'); |
| 54 | + |
| 55 | +INSERT INTO tradelog |
| 56 | +VALUES (1, 'aaaaaaaa', 1000, now()); |
| 57 | +INSERT INTO tradelog |
| 58 | +VALUES (2, 'aaaaaaab', 1000, now()); |
| 59 | +INSERT INTO tradelog |
| 60 | +VALUES (3, 'aaaaaaac', 1000, now()); |
| 61 | + |
| 62 | +DELIMITER ;; |
| 63 | +DROP PROCEDURE IF EXISTS init; |
| 64 | +CREATE PROCEDURE init() |
| 65 | +BEGIN |
| 66 | + DECLARE i INT; |
| 67 | + SET i = 3; |
| 68 | + WHILE i < 10000 |
| 69 | + DO |
| 70 | + INSERT INTO tradelog(tradeid, operator, t_modified) |
| 71 | + VALUES (concat(char(97 + (i DIV 1000)), char(97 + (i % 1000 DIV 100)), char(97 + (i % 100 DIV 10)), |
| 72 | + char(97 + (i % 10))), i, now()); |
| 73 | + SET i = i + 1; |
| 74 | + END WHILE; |
| 75 | +END;; |
| 76 | +DELIMITER ; |
| 77 | +CALL init(); |
| 78 | + |
| 79 | +-- 步骤 3、执行计划查看SQL效率 |
| 80 | +-- 3.1.1 此 SQL 对索引字段做函数操作,优化器会放弃走树搜索功能,改为全表扫描 |
| 81 | +EXPLAIN |
| 82 | +SELECT count(*) |
| 83 | +FROM tradelog |
| 84 | +WHERE month(t_modified) = 7; |
| 85 | + |
| 86 | +-- 3.1.2 SQL 优化 |
| 87 | +EXPLAIN |
| 88 | +SELECT count(*) |
| 89 | +FROM tradelog |
| 90 | +WHERE (t_modified >= '2016-7-1' AND t_modified < '2016-8-1') OR |
| 91 | + (t_modified >= '2017-7-1' AND t_modified < '2017-8-1') OR |
| 92 | + (t_modified >= '2018-7-1' AND t_modified < '2018-8-1'); |
| 93 | + |
| 94 | +-- 3.2.1 此 SQL 对索引字段隐式的使用了转换函数操作,优化器会放弃走树搜索功能,改为全表扫描 |
| 95 | +-- 相当于 select * from tradelog where CAST(tradid AS signed int) = 110717; |
| 96 | +EXPLAIN |
| 97 | +SELECT * |
| 98 | +FROM tradelog |
| 99 | +WHERE tradeid = 110717; |
| 100 | + |
| 101 | +-- 3.3.1 下面两条 SQL 的扫描行数不同 |
| 102 | +-- 原因是:字符集 utf8mb4 是 utf8 的超集,所以当这两个类型的字符串在做比较的时候, |
| 103 | +-- MySQL 内部的操作是,先把 utf8 字符串转成 utf8mb4 字符集,再做比较。 |
| 104 | +# 需要做字符编码转换 |
| 105 | +EXPLAIN |
| 106 | +SELECT d.* |
| 107 | +FROM tradelog l, trade_detail d |
| 108 | +WHERE d.tradeid = l.tradeid AND l.id = 2; |
| 109 | + |
| 110 | +# 上面的 SQL 等价于这条注掉的 SQL |
| 111 | +# SELECT * |
| 112 | +# FROM trade_detail |
| 113 | +# WHERE CONVERT(traideid USING utf8mb4) = $l2.tradeid.value; |
| 114 | + |
| 115 | +# 不需要做字符编码转换 |
| 116 | +EXPLAIN |
| 117 | +SELECT l.operator |
| 118 | +FROM tradelog l, trade_detail d |
| 119 | +WHERE d.tradeid = l.tradeid AND d.id = 2; |
0 commit comments