Content:`很多初学者会将ALTER TABLE tbl_name [DEFAULT] CHARACTER SET 'UTF8'误认为会修改所有字段的字符集,但实际上它只会影响后续新增的字段不会改表已有字段的字符集。如果想修改整张表所有字段的字符集建议使用ALTER TABLE tbl_name CONVERT TO CHARACTER SET charset_name;`,
Content:"正确的作法是col IN ('val1', 'val2', 'val3') OR col IS NULL",
},
"ARG.005":{
Summary:"IN要慎用,元素过多会导致全表扫描",
Content:` 如:select id from t where num in(1,2,3)对于连续的数值,能用BETWEEN就不要用IN了:select id from t where num between 1 and 3。而当IN值过多时MySQL也可能会进入全表扫描导致性能急剧下降。`,
},
"ARG.006":{
Summary:"应尽量避免在WHERE子句中对字段进行NULL值判断",
Content:`使用IS NULL或IS NOT NULL将可能导致引擎放弃使用索引而进行全表扫描,如:select id from t where num is null;可以在num上设置默认值0,确保表中num列没有null值,然后这样查询: select id from t where num=0;`,
The HAVING clause was originally added to SQL because the WHERE keyword could not be used with aggregate functions. HAVING is typically used with the GROUP BY clause to restrict the groups of returned rows to only those that meet certain conditions. However, if you use this clause in your query, the index is not used, which -as you already know- can result in a query that doesn't really perform all that well.
If you’re looking for an alternative, consider using the WHERE clause. Consider the following queries:
SELECT state, COUNT(*)
FROM Drivers
WHERE state IN ('GA', 'TX')
GROUP BY state
ORDER BY state
SELECT state, COUNT(*)
FROM Drivers
GROUP BY state
HAVING state IN ('GA', 'TX')
ORDER BY state
The first query uses the WHERE clause to restrict the number of rows that need to be summed, whereas the second query sums up all the rows in the table and then uses HAVING to throw away the sums it calculated. In these types of cases, the alternative with the WHERE clause is obviously the better one, as you don’t waste any resources.
You see that this is not about limiting the result set, rather about limiting the intermediate number of records within a query.
Note that the difference between these two clauses lies in the fact that the WHERE clause introduces a condition on individual rows, while the HAVING clause introduces a condition on aggregations or results of a selection where a single result, such as MIN, MAX, SUM,… has been produced from multiple rows.
Content:`由于WHERE条件错误使得OUTER JOIN的外部表无数据返回,这会将查询隐式转换为 INNER JOIN 。如:select c from L left join R using(c) where L.a=5 and R.b=10。这种SQL逻辑上可能存在错误或程序员对OUTER JOIN如何工作存在误解,因为LEFT/RIGHT JOIN是LEFT/RIGHT OUTER JOIN的缩写。`,
},
"JOI.004":{
Summary:"不建议使用排它JOIN",
Content:`只在右侧表为NULL的带WHERE子句的LEFT OUTER JOIN语句,有可能是在WHERE子句中使用错误的列,如:“... FROM l LEFT OUTER JOIN r ON l.l = r.r WHERE r.z IS NULL”,这个查询正确的逻辑可能是 WHERE r.r IS NULL。`,
Content:"SELECT INTO OUTFILE需要授予FILE权限,这通过会引入安全问题。LOAD DATA虽然可以提高数据导入速度,但同时也可能导致从库同步延迟过大。",
},
"SEC.001":{
Summary:"请谨慎使用TRUNCATE操作",
Content:`一般来说想清空一张表最快速的做法就是使用TRUNCATE TABLE tbl_name;语句。但TRUNCATE操作也并非是毫无代价的,TRUNCATE TABLE无法返回被删除的准确行数,如果需要返回被删除的行数建议使用DELETE语法。TRUNCATE操作还会重置AUTO_INCREMENT,如果不想重置该值建议使用DELETE FROM tbl_name WHERE 1;替代。TRUNCATE操作会对数据字典添加源数据锁(MDL),当一次需要TRUNCATE很多表时会影响整个实例的所有请求,因此如果要TRUNCATE多个表建议用DROP+CREATE的方式以减少锁时长。`,
"JOI.001": {Item:"JOI.001", Severity:"L2", Summary:"JOIN语句混用逗号和ANSI模式", Content:"表连接的时候混用逗号和ANSI JOIN不便于人类理解,并且MySQL不同版本的表连接行为和优先级均有所不同,当MySQL版本变化后可能会引入错误。", Case:"select c1,c2,c3 from t1,t2 join t3 on t1.c1=t2.c1,t1.c3=t3,c1 where id>1000", Position:0, Func:func(*advisor.Query4Audit) advisor.Rule {...}},
"ARG.006": {Item:"ARG.006", Severity:"L1", Summary:"应尽量避免在WHERE子句中对字段进行NULL值判断", Content:"使用IS NULL或IS NOT NULL将可能导致引擎放弃使用索引而进行全表扫描,如:select id from t where num is null;可以在num上设置默认值0,确保表中num列没有null值,然后这样查询: select id from t where num=0;", Case:"select id from t where num is null", Position:0, Func:func(*advisor.Query4Audit) advisor.Rule {...}},
"CLA.003": {Item:"CLA.003", Severity:"L2", Summary:"不建议使用带OFFSET的LIMIT查询", Content:"使用LIMIT和OFFSET对结果集分页的复杂度是O(n^2),并且会随着数据增大而导致性能问题。采用“书签”扫描的方法实现分页效率更高。", Case:"select c1,c2 from tbl where name=xx order by number limit 1 offset 20", Position:0, Func:func(*advisor.Query4Audit) advisor.Rule {...}},
"FUN.001": {Item:"FUN.001", Severity:"L2", Summary:"避免在WHERE条件中使用函数或其他运算符", Content:"虽然在SQL中使用函数可以简化很多复杂的查询,但使用了函数的查询无法利用表中已经建立的索引,该查询将会是全表扫描,性能较差。通常建议将列名写在比较运算符左侧,将查询过滤条件放在比较运算符右侧。", Case:"select id from t where substring(name,1,3)='abc'", Position:0, Func:func(*advisor.Query4Audit) advisor.Rule {...}},
"SUB.005": {Item:"SUB.005", Severity:"L8", Summary:"子查询不支持LIMIT", Content:"当前MySQL版本不支持在子查询中进行'LIMIT & IN/ALL/ANY/SOME'。", Case:"SELECT * FROM staff WHERE name IN (SELECT NAME FROM customer ORDER BY name LIMIT 1)", Position:0, Func:func(*advisor.Query4Audit) advisor.Rule {...}},
"CLA.013": {Item:"CLA.013", Severity:"L3", Summary:"不建议使用HAVING子句", Content:"将查询的HAVING子句改写为WHERE中的查询条件,可以在查询处理期间使用索引。", Case:"SELECT s.c_id,count(s.c_id) FROM s where c = test GROUP BY s.c_id HAVING s.c_id <> '1660' AND s.c_id <> '2' order by s.c_id", Position:0, Func:func(*advisor.Query4Audit) advisor.Rule {...}},
"SUB.003": {Item:"SUB.003", Severity:"L3", Summary:"考虑使用EXISTS而不是DISTINCT子查询", Content:"DISTINCT关键字在对元组排序后删除重复。相反,考虑使用一个带有EXISTS关键字的子查询,您可以避免返回整个表。", Case:"SELECT DISTINCT c.c_id, c.c_name FROM c,e WHERE e.c_id = c.c_id", Position:0, Func:func(*advisor.Query4Audit) advisor.Rule {...}},
"ARG.007": {Item:"ARG.007", Severity:"L3", Summary:"避免使用模式匹配", Content:"性能问题是使用模式匹配操作符的最大缺点。使用LIKE或正则表达式进行模式匹配进行查询的另一个问题,是可能会返回意料之外的结果。最好的方案就是使用特殊的搜索引擎技术来替代SQL,比如Apache Lucene。另一个可选方案是将结果保存起来从而减少重复的搜索开销。如果一定要使用SQL,请考虑在MySQL中使用像FULLTEXT索引这样的第三方扩展。但更广泛地说,您不一定要使用SQL来解决所有问题。", Case:"select c_id,c2,c3 from tbl where c2 like 'test%'", Position:0, Func:func(*advisor.Query4Audit) advisor.Rule {...}},
"ARG.011": {Item:"ARG.011", Severity:"L3", Summary:"不要使用负向查询,如:NOT IN/NOT LIKE", Content:"请尽量不要使用负向查询,这将导致全表扫描,对查询性能影响较大。", Case:"select id from t where num not in(1,2,3);", Position:0, Func:func(*advisor.Query4Audit) advisor.Rule {...}},
"KEY.009": {Item:"KEY.009", Severity:"L0", Summary:"添加唯一索引前请注意检查数据唯一性", Content:"请提前检查添加唯一索引列的数据唯一性,如果数据不唯一在线表结构调整时将有可能自动将重复列删除,这有可能导致数据丢失。", Case:"CREATE UNIQUE INDEX part_of_name ON customer (name(10));", Position:0, Func:func(*advisor.Query4Audit) advisor.Rule {...}},
"FUN.002": {Item:"FUN.002", Severity:"L1", Summary:"指定了WHERE条件或非MyISAM引擎时使用COUNT(*)操作性能不佳", Content:"COUNT(*)的作用是统计表行数,COUNT(COL)的作用是统计指定列非NULL的行数。MyISAM表对于COUNT(*)统计全表行数进行了特殊的优化,通常情况下非常快。但对于非MyISAM表或指定了某些WHERE条件,COUNT(*)操作需要扫描大量的行才能获取精确的结果,性能也因此不佳。有时候某些业务场景并不需要完全精确的COUNT值,此时可以用近似值来代替。EXPLAIN出来的优化器估算的行数就是一个不错的近似值,执行EXPLAIN并不需要真正去执行查询,所以成本很低。", Case:"SELECT c3, COUNT(*) AS accounts FROM tab where c2 < 10000 GROUP BY c3 ORDER BY num", Position:0, Func:func(*advisor.Query4Audit) advisor.Rule {...}},
"JOI.003": {Item:"JOI.003", Severity:"L4", Summary:"OUTER JOIN失效", Content:"由于WHERE条件错误使得OUTER JOIN的外部表无数据返回,这会将查询隐式转换为 INNER JOIN 。如:select c from L left join R using(c) where L.a=5 and R.b=10。这种SQL逻辑上可能存在错误或程序员对OUTER JOIN如何工作存在误解,因为LEFT/RIGHT JOIN是LEFT/RIGHT OUTER JOIN的缩写。", Case:"select c1,c2,c3 from t1 left outer join t2 using(c1) where t1.c2=2 and t2.c3=4", Position:0, Func:func(*advisor.Query4Audit) advisor.Rule {...}},
"TBL.001": {Item:"TBL.001", Severity:"L4", Summary:"不建议使用分区表", Content:"不建议使用分区表", Case:"CREATE TABLE trb3(id INT, name VARCHAR(50), purchased DATE) PARTITION BY RANGE(YEAR(purchased)) (PARTITION p0 VALUES LESS THAN (1990), PARTITION p1 VALUES LESS THAN (1995), PARTITION p2 VALUES LESS THAN (2000), PARTITION p3 VALUES LESS THAN (2005) );", Position:0, Func:func(*advisor.Query4Audit) advisor.Rule {...}},
"LIT.002": {Item:"LIT.002", Severity:"L4", Summary:"日期/时间未使用引号括起", Content:"诸如“WHERE col <2010-02-12”之类的查询是有效的SQL,但可能是一个错误,因为它将被解释为“WHERE col <1996”; 日期/时间文字应该加引号。", Case:"select col1,col2 from tbl where time < 2018-01-10", Position:0, Func:func(*advisor.Query4Audit) advisor.Rule {...}},
"CLA.010": {Item:"CLA.010", Severity:"L2", Summary:"GROUP BY的条件为表达式", Content:"当GROUP BY条件为表达式或函数时会使用到临时表,如果在未指定WHERE或WHERE条件返回的结果集较大时性能会很差。", Case:"select description from film where title ='ACADEMY DINOSAUR' GROUP BY length-language_id;", Position:0, Func:func(*advisor.Query4Audit) advisor.Rule {...}},
"ARG.002": {Item:"ARG.002", Severity:"L1", Summary:"没有通配符的LIKE查询", Content:"不包含通配符的LIKE查询可能存在逻辑错误,因为逻辑上它与等值查询相同。", Case:"select c1,c2,c3 from tbl where name like 'foo'", Position:0, Func:func(*advisor.Query4Audit) advisor.Rule {...}},
"JOI.004": {Item:"JOI.004", Severity:"L4", Summary:"不建议使用排它JOIN", Content:"只在右侧表为NULL的带WHERE子句的LEFT OUTER JOIN语句,有可能是在WHERE子句中使用错误的列,如:“... FROM l LEFT OUTER JOIN r ON l.l = r.r WHERE r.z IS NULL”,这个查询正确的逻辑可能是 WHERE r.r IS NULL。", Case:"select c1,c2,c3 from t1 left outer join t2 on t1.c1=t2.c1 where t2.c2 is null", Position:0, Func:func(*advisor.Query4Audit) advisor.Rule {...}},
"ALT.001": {Item:"ALT.001", Severity:"L4", Summary:"修改表的默认字符集不会改表各个字段的字符集", Content:"很多初学者会将ALTER TABLE tbl_name [DEFAULT] CHARACTER SET 'UTF8'误认为会修改所有字段的字符集,但实际上它只会影响后续新增的字段不会改表已有字段的字符集。如果想修改整张表所有字段的字符集建议使用ALTER TABLE tbl_name CONVERT TO CHARACTER SET charset_name;", Case:"ALTER TABLE tbl_name CONVERT TO CHARACTER SET charset_name;", Position:0, Func:func(*advisor.Query4Audit) advisor.Rule {...}},
"SUB.006": {Item:"SUB.006", Severity:"L2", Summary:"不建议在子查询中使用函数", Content:"MySQL将外部查询中的每一行作为依赖子查询执行子查询,如果在子查询中使用函数,即使是semi-join也很难进行高效的查询。可以将子查询重写为OUTER JOIN语句并用连接条件对数据进行过滤。", Case:"SELECT * FROM staff WHERE name IN (SELECT max(NAME) FROM customer)", Position:0, Func:func(*advisor.Query4Audit) advisor.Rule {...}},
"CLA.008": {Item:"CLA.008", Severity:"L2", Summary:"请为GROUP BY显示添加ORDER BY条件", Content:"默认MySQL会对'GROUP BY col1, col2, ...'请求按如下顺序排序'ORDER BY col1, col2, ...'。如果GROUP BY语句不指定ORDER BY条件会导致无谓的排序产生,如果不需要排序建议添加'ORDER BY NULL'。", Case:"select c1,c2,c3 from t1 where c1='foo' group by c2", Position:0, Func:func(*advisor.Query4Audit) advisor.Rule {...}},
"ARG.005": {Item:"ARG.005", Severity:"L1", Summary:"IN要慎用,元素过多会导致全表扫描", Content:" 如:select id from t where num in(1,2,3)对于连续的数值,能用BETWEEN就不要用IN了:select id from t where num between 1 and 3。而当IN值过多时MySQL也可能会进入全表扫描导致性能急剧下降。", Case:"select id from t where num in(1,2,3)", Position:0, Func:func(*advisor.Query4Audit) advisor.Rule {...}},
"CLA.006": {Item:"CLA.006", Severity:"L4", Summary:"在不同的表中GROUP BY或ORDER BY", Content:"这将强制使用临时表和filesort,可能产生巨大性能隐患,并且可能消耗大量内存和磁盘上的临时空间。", Case:"select tb1.col, tb2.col from tb1, tb2 where id=1 group by tb1.col, tb2.col", Position:0, Func:func(*advisor.Query4Audit) advisor.Rule {...}},
"STA.001": {Item:"STA.001", Severity:"L0", Summary:"'!=' 运算符是非标准的", Content:"\"<>\"才是标准SQL中的不等于运算符。", Case:"select col1,col2 from tbl where type!=0", Position:0, Func:func(*advisor.Query4Audit) advisor.Rule {...}},
"ARG.003": {Item:"ARG.003", Severity:"L4", Summary:"参数比较包含隐式转换,无法使用索引", Content:"隐式类型转换有无法命中索引的风险,在高并发、大数据量的情况下,命不中索引带来的后果非常严重。", Case:"SELECT * FROM sakila.film WHERE length >= '60';", Position:0, Func:func(*advisor.Query4Audit) advisor.Rule {...}},
"COL.001": {Item:"COL.001", Severity:"L1", Summary:"SELECT * is not good", Content:"当表结构变更时,使用*通配符选择所有列将导致查询的含义和行为会发生更改,可能导致查询返回更多的数据。", Case:"select * from tbl where id=1", Position:0, Func:func(*advisor.Query4Audit) advisor.Rule {...}},
"ALI.001": {Item:"ALI.001", Severity:"L0", Summary:"建议使用AS关键字显示声明一个别名", Content:"在列或表别名(如\"tbl AS alias\")中, 明确使用AS关键字比隐含别名(如\"tbl alias\")更易懂。", Case:"select name from tbl t1 where id < 1000", Position:0, Func:func(*advisor.Query4Audit) advisor.Rule {...}},
"KEY.005": {Item:"KEY.005", Severity:"L2", Summary:"表建的索引过多", Content:"表建的索引过多", Case:"CREATE TABLE tbl ( a int, b int, c int, KEY idx_a (`a`),KEY idx_b(`b`),KEY idx_c(`c`));", Position:0, Func:func(*advisor.Query4Audit) advisor.Rule {...}},
"STA.003": {Item:"STA.003", Severity:"L1", Summary:"索引起名不规范", Content:"建议普通二级索引以idx_为前缀,唯一索引以uk_为前缀。", Case:"select col from now where type!=0", Position:0, Func:func(*advisor.Query4Audit) advisor.Rule {...}},
"GRP.001": {Item:"GRP.001", Severity:"L2", Summary:"不建议对等值查询列使用GROUP BY", Content:"GROUP BY中的列在前面的WHERE条件中使用了等值查询,对这样的列进行GROUP BY意义不大。", Case:"select film_id, title from film where release_year='2006' group by release_year", Position:0, Func:func(*advisor.Query4Audit) advisor.Rule {...}},
"RES.007": {Item:"RES.007", Severity:"L4", Summary:"永远为真的比较条件", Content:"查询条件永远为真,这将导致WHERE条件失效进行全表查询。", Case:"select * from tbl where 1 = 1;", Position:0, Func:func(*advisor.Query4Audit) advisor.Rule {...}},
"CLA.001": {Item:"CLA.001", Severity:"L4", Summary:"No where condition for select statement", Content:"SELECT语句没有WHERE子句,可能检查比预期更多的行(全表扫描)。对于SELECT COUNT(*)类型的请求如果不要求精度,建议使用SHOW TABLE STATUS或EXPLAIN替代。", Case:"select id from tbl", Position:0, Func:func(*advisor.Query4Audit) advisor.Rule {...}},
"SEC.001": {Item:"SEC.001", Severity:"L0", Summary:"请谨慎使用TRUNCATE操作", Content:"一般来说想清空一张表最快速的做法就是使用TRUNCATE TABLE tbl_name;语句。但TRUNCATE操作也并非是毫无代价的,TRUNCATE TABLE无法返回被删除的准确行数,如果需要返回被删除的行数建议使用DELETE语法。TRUNCATE操作还会重置AUTO_INCREMENT,如果不想重置该值建议使用DELETE FROM tbl_name WHERE 1;替代。TRUNCATE操作会对数据字典添加源数据锁(MDL),当一次需要TRUNCATE很多表时会影响整个实例的所有请求,因此如果要TRUNCATE多个表建议用DROP+CREATE的方式以减少锁时长。", Case:"TRUNCATE TABLE tbl_name", Position:0, Func:func(*advisor.Query4Audit) advisor.Rule {...}},
"ALI.003": {Item:"ALI.003", Severity:"L1", Summary:"别名不要与表或列的名字相同", Content:"表或列的别名与其真实名称相同, 这样的别名会使得查询更难去分辨。", Case:"select name from tbl as tbl where id < 1000", Position:0, Func:func(*advisor.Query4Audit) advisor.Rule {...}},
"KEY.008": {Item:"KEY.008", Severity:"L4", Summary:"ORDER BY多个列但排序方向不同时可能无法使用索引", Content:"在MySQL 8.0之前当ORDER BY多个列指定的排序方向不同时将无法使用已经建立的索引。", Case:"SELECT * FROM tbl ORDER BY a DESC, b ASC;", Position:0, Func:func(*advisor.Query4Audit) advisor.Rule {...}},
"CLA.002": {Item:"CLA.002", Severity:"L3", Summary:"不建议使用ORDER BY RAND()", Content:"ORDER BY RAND()是从结果集中检索随机行的一种非常低效的方法,因为它会对整个结果进行排序并丢弃其大部分数据。", Case:"select name from tbl where id < 1000 order by rand(number)", Position:0, Func:func(*advisor.Query4Audit) advisor.Rule {...}},
"JOI.007": {Item:"JOI.007", Severity:"L4", Summary:"不建议使用联表更新", Content:"当需要同时更新多张表时建议使用简单SQL,一条SQL只更新一张表,尽量不要将多张表的更新在同一条SQL中完成。", Case:"UPDATE users u LEFT JOIN hobby h ON u.id = h.uid SET u.name = 'pianoboy' WHERE h.hobby = 'piano';", Position:0, Func:func(*advisor.Query4Audit) advisor.Rule {...}},
"SEC.003": {Item:"SEC.003", Severity:"L0", Summary:"使用DELETE/DROP/TRUNCATE等操作时注意备份", Content:"在执行高危操作之前对数据进行备份是十分有必要的。", Case:"delete from table where col = 'condition'", Position:0, Func:func(*advisor.Query4Audit) advisor.Rule {...}},
"JOI.005": {Item:"JOI.005", Severity:"L2", Summary:"减少JOIN的数量", Content:"太多的JOIN是复杂的裹脚布式查询的症状。考虑将复杂查询分解成许多简单的查询,并减少JOIN的数量。", Case:"select bp1.p_id, b1.d_d as l, b1.b_id from b1 join bp1 on (b1.b_id = bp1.b_id) left outer join (b1 as b2 join bp2 on (b2.b_id = bp2.b_id)) on (bp1.p_id = bp2.p_id ) join bp21 on (b1.b_id = bp1.b_id) join bp31 on (b1.b_id = bp1.b_id) join bp41 on (b1.b_id = bp1.b_id) where b2.b_id = 0", Position:0, Func:func(*advisor.Query4Audit) advisor.Rule {...}},
"ALT.002": {Item:"ALT.002", Severity:"L2", Summary:"同一张表的多条ALTER请求建议合为一条", Content:"每次表结构变更对线上服务都会产生影响,即使是能够通过在线工具进行调整也请尽量通过合并ALTER请求的试减少操作次数。", Case:"ALTER TABLE tbl ADD COLUMN col int, ADD INDEX idx_col (`col`);", Position:0, Func:func(*advisor.Query4Audit) advisor.Rule {...}},
"CLA.005": {Item:"CLA.005", Severity:"L2", Summary:"ORDER BY常数列没有任何意义", Content:"SQL逻辑上可能存在错误; 最多只是一个无用的操作,不会更改查询结果。", Case:"select id from test where id=1 order by id", Position:0, Func:func(*advisor.Query4Audit) advisor.Rule {...}},
"CLA.009": {Item:"CLA.009", Severity:"L2", Summary:"ORDER BY的条件为表达式", Content:"当ORDER BY条件为表达式或函数时会使用到临时表,如果在未指定WHERE或WHERE条件返回的结果集较大时性能会很差。", Case:"select description from film where title ='ACADEMY DINOSAUR' order by length-language_id;", Position:0, Func:func(*advisor.Query4Audit) advisor.Rule {...}},
"LCK.001": {Item:"LCK.001", Severity:"L3", Summary:"INSERT INTO xx SELECT加锁粒度较大请谨慎", Content:"INSERT INTO xx SELECT加锁粒度较大请谨慎", Case:"INSERT INTO tbl SELECT * FROM tbl2;", Position:0, Func:func(*advisor.Query4Audit) advisor.Rule {...}},
"ALI.002": {Item:"ALI.002", Severity:"L8", Summary:"不建议给列通配符'*'设置别名", Content:"例: \"SELECT tbl.* col1, col2\"上面这条SQL给列通配符设置了别名,这样的SQL可能存在逻辑错误。您可能意在查询col1, 但是代替它的是重命名的是tbl的最后一列。", Case:"select tbl.* as c1,c2,c3 from tbl where id < 1000", Position:0, Func:func(*advisor.Query4Audit) advisor.Rule {...}},
"JOI.006": {Item:"JOI.006", Severity:"L4", Summary:"将嵌套查询重写为JOIN通常会导致更高效的执行和更有效的优化", Content:"一般来说,非嵌套子查询总是用于关联子查询,最多是来自FROM子句中的一个表,这些子查询用于ANY、ALL和EXISTS的谓词。如果可以根据查询语义决定子查询最多返回一个行,那么一个不相关的子查询或来自FROM子句中的多个表的子查询就被压平了。", Case:"SELECT s,p,d FROM tbl WHERE p.p_id = (SELECT s.p_id FROM tbl WHERE s.c_id = 100996 AND s.q = 1 )", Position:0, Func:func(*advisor.Query4Audit) advisor.Rule {...}},
"LCK.002": {Item:"LCK.002", Severity:"L3", Summary:"请慎用INSERT ON DUPLICATE KEY UPDATE", Content:"当主键为自增键时使用INSERT ON DUPLICATE KEY UPDATE可能会导致主键出现大量不连续快速增长,导致主键快速溢出无法继续写入。极端情况下还有可能导致主从数据不一致。", Case:"INSERT INTO t1(a,b,c) VALUES (1,2,3) ON DUPLICATE KEY UPDATE c=c+1;", Position:0, Func:func(*advisor.Query4Audit) advisor.Rule {...}},
"DIS.001": {Item:"DIS.001", Severity:"L1", Summary:"消除不必要的DISTINCT条件", Content:"太多DISTINCT条件是复杂的裹脚布式查询的症状。考虑将复杂查询分解成许多简单的查询,并减少DISTINCT条件的数量。如果主键列是列的结果集的一部分,则DISTINCT条件可能没有影响。", Case:"SELECT DISTINCT c.c_id,count(DISTINCT c.c_name),count(DISTINCT c.c_e),count(DISTINCT c.c_n),count(DISTINCT c.c_me),c.c_d FROM (select distinct xing, name from B) as e WHERE e.country_id = c.country_id", Position:0, Func:func(*advisor.Query4Audit) advisor.Rule {...}},
"RES.004": {Item:"RES.004", Severity:"L4", Summary:"UPDATE/DELETE操作指定了ORDER BY条件", Content:"UPDATE/DELETE操作不要指定ORDER BY条件。", Case:"UPDATE film SET length = 120 WHERE title = 'abc' ORDER BY title", Position:0, Func:func(*advisor.Query4Audit) advisor.Rule {...}},
"JOI.002": {Item:"JOI.002", Severity:"L4", Summary:"同一张表被连接两次", Content:"相同的表在FROM子句中至少出现两次,可以简化为对该表的单次访问。", Case:"select tb1.col from (tb1, tb2) join tb2 on tb1.id=tb.id where tb1.id=1", Position:0, Func:func(*advisor.Query4Audit) advisor.Rule {...}},
"SUB.004": {Item:"SUB.004", Severity:"L3", Summary:"执行计划中嵌套连接深度过深", Content:"MySQL对子查询的优化效果不佳,MySQL将外部查询中的每一行作为依赖子查询执行子查询。 这是导致严重性能问题的常见原因。", Case:"SELECT * from tb where id in (select id from (select id from tb))", Position:0, Func:func(*advisor.Query4Audit) advisor.Rule {...}},
"RES.008": {Item:"RES.008", Severity:"L2", Summary:"不建议使用LOAD DATA/SELECT ... INTO OUTFILE", Content:"SELECT INTO OUTFILE需要授予FILE权限,这通过会引入安全问题。LOAD DATA虽然可以提高数据导入速度,但同时也可能导致从库同步延迟过大。", Case:"LOAD DATA INFILE 'data.txt' INTO TABLE db2.my_table;", Position:0, Func:func(*advisor.Query4Audit) advisor.Rule {...}},
"ARG.010": {Item:"ARG.010", Severity:"L1", Summary:"不要使用hint,如sql_no_cache, force index, ignore key, straight join等", Content:"hint是用来强制SQL按照某个执行计划来执行,但随着数据量变化我们无法保证自己当初的预判是正确的。", Case:"SELECT * FROM t1 USE INDEX (i1) ORDER BY a;", Position:0, Func:func(*advisor.Query4Audit) advisor.Rule {...}},
"SUB.002": {Item:"SUB.002", Severity:"L2", Summary:"如果您不在乎重复的话,建议使用UNION ALL替代UNION", Content:"与去除重复的UNION不同,UNION ALL允许重复元组。如果您不关心重复元组,那么使用UNION ALL将是一个更快的选项。", Case:"select teacher_id as id,people_name as name from t1,t2 where t1.teacher_id=t2.people_id union select student_id as id,people_name as name from t1,t2 where t1.student_id=t2.people_id", Position:0, Func:func(*advisor.Query4Audit) advisor.Rule {...}},
"ARG.004": {Item:"ARG.004", Severity:"L4", Summary:"IN (NULL)/NOT IN (NULL)永远非真", Content:"正确的作法是col IN ('val1', 'val2', 'val3') OR col IS NULL", Case:"SELECT * FROM tb WHERE col IN (NULL);", Position:0, Func:func(*advisor.Query4Audit) advisor.Rule {...}},
"CLA.004": {Item:"CLA.004", Severity:"L2", Summary:"不建议对常量进行GROUP BY", Content:"GROUP BY 1 表示按第一列进行GROUP BY。如果在GROUP BY子句中使用数字,而不是表达式或列名称,当查询列顺序改变时,可能会导致问题。", Case:"select col1,col2 from tbl group by 1", Position:0, Func:func(*advisor.Query4Audit) advisor.Rule {...}},
"ARG.001": {Item:"ARG.001", Severity:"L4", Summary:"不建议使用前项通配符查找", Content:"例如“%foo”,查询参数有一个前项通配符的情况无法使用已有索引。", Case:"select c1,c2,c3 from tbl where name like '%foo'", Position:0, Func:func(*advisor.Query4Audit) advisor.Rule {...}},
"RES.001": {Item:"RES.001", Severity:"L4", Summary:"非确定性的GROUP BY", Content:"SQL返回的列既不在聚合函数中也不是GROUP BY表达式的列中,因此这些值的结果将是非确定性的。如:select a, b, c from tbl where foo=\"bar\" group by a,该SQL返回的结果就是不确定的。", Case:"select c1,c2,c3 from t1 where c2='foo' group by c2", Position:0, Func:func(*advisor.Query4Audit) advisor.Rule {...}},