提交 f458efea authored 作者: Thomas Mueller's avatar Thomas Mueller

The new statement EXPLAIN ANALYZE executes the statement, and displays the query…

The new statement EXPLAIN ANALYZE executes the statement, and displays the query plan with the actual row scan count for each table.
上级 8ba7ad40
...@@ -83,9 +83,11 @@ CALL 15*25 ...@@ -83,9 +83,11 @@ CALL 15*25
" "
"Commands (DML)","EXPLAIN"," "Commands (DML)","EXPLAIN","
EXPLAIN [ PLAN FOR ] { select | insert | update | delete } EXPLAIN { [ PLAN FOR ] | ANALYZE } { select | insert | update | delete }
"," ","
Shows the execution plan for a statement. Shows the execution plan for a statement.
When using EXPLAIN ANALYZE, the statement is actually executed, and the query plan
will include the actual row scan count for each table.
"," ","
EXPLAIN SELECT * FROM TEST WHERE ID=1 EXPLAIN SELECT * FROM TEST WHERE ID=1
" "
......
...@@ -18,7 +18,9 @@ Change Log ...@@ -18,7 +18,9 @@ Change Log
<h1>Change Log</h1> <h1>Change Log</h1>
<h2>Next Version (unreleased)</h2> <h2>Next Version (unreleased)</h2>
<ul><li>H2 Console: the auto-complete feature didn't quote column names <ul><li>The new statement EXPLAIN ANALYZE executes the statement,
and displays the query plan with the actual row scan count for each table.
</li><li>H2 Console: the auto-complete feature didn't quote column names
that need quoting. Issue 186. that need quoting. Issue 186.
</li><li>The experimental LOB storage mechanism now supports all features of the </li><li>The experimental LOB storage mechanism now supports all features of the
old one. To use it, set the system property "h2.lobInDatabase" to "true". old one. To use it, set the system property "h2.lobInDatabase" to "true".
......
...@@ -59,7 +59,7 @@ import org.h2.command.dml.BackupCommand; ...@@ -59,7 +59,7 @@ import org.h2.command.dml.BackupCommand;
import org.h2.command.dml.Call; import org.h2.command.dml.Call;
import org.h2.command.dml.Delete; import org.h2.command.dml.Delete;
import org.h2.command.dml.ExecuteProcedure; import org.h2.command.dml.ExecuteProcedure;
import org.h2.command.dml.ExplainPlan; import org.h2.command.dml.Explain;
import org.h2.command.dml.Insert; import org.h2.command.dml.Insert;
import org.h2.command.dml.Merge; import org.h2.command.dml.Merge;
import org.h2.command.dml.NoOperation; import org.h2.command.dml.NoOperation;
...@@ -1330,10 +1330,15 @@ public class Parser { ...@@ -1330,10 +1330,15 @@ public class Parser {
return command; return command;
} }
private ExplainPlan parseExplain() { private Explain parseExplain() {
ExplainPlan command = new ExplainPlan(session); Explain command = new Explain(session);
readIf("PLAN"); if (readIf("ANALYZE")) {
readIf("FOR"); command.setExecuteCommand(true);
} else {
if (readIf("PLAN")) {
readIf("FOR");
}
}
if (isToken("SELECT") || isToken("FROM") || isToken("(")) { if (isToken("SELECT") || isToken("FROM") || isToken("(")) {
command.setCommand(parseSelect()); command.setCommand(parseSelect());
} else if (readIf("DELETE")) { } else if (readIf("DELETE")) {
......
...@@ -20,12 +20,13 @@ import org.h2.value.ValueString; ...@@ -20,12 +20,13 @@ import org.h2.value.ValueString;
* This class represents the statement * This class represents the statement
* EXPLAIN * EXPLAIN
*/ */
public class ExplainPlan extends Prepared { public class Explain extends Prepared {
private Prepared command; private Prepared command;
private LocalResult result; private LocalResult result;
private boolean executeCommand;
public ExplainPlan(Session session) { public Explain(Session session) {
super(session); super(session);
} }
...@@ -37,6 +38,10 @@ public class ExplainPlan extends Prepared { ...@@ -37,6 +38,10 @@ public class ExplainPlan extends Prepared {
command.prepare(); command.prepare();
} }
public void setExecuteCommand(boolean executeCommand) {
this.executeCommand = executeCommand;
}
public ResultInterface queryMeta() { public ResultInterface queryMeta() {
return query(-1); return query(-1);
} }
...@@ -47,6 +52,13 @@ public class ExplainPlan extends Prepared { ...@@ -47,6 +52,13 @@ public class ExplainPlan extends Prepared {
Expression[] expressions = { expr }; Expression[] expressions = { expr };
result = new LocalResult(session, expressions, 1); result = new LocalResult(session, expressions, 1);
if (maxrows >= 0) { if (maxrows >= 0) {
if (executeCommand) {
if (command.isQuery()) {
command.query(maxrows);
} else {
command.update();
}
}
String plan = command.getPlanSQL(); String plan = command.getPlanSQL();
add(plan); add(plan);
} }
......
...@@ -503,6 +503,9 @@ public class TableFilter implements ColumnResolver { ...@@ -503,6 +503,9 @@ public class TableFilter implements ColumnResolver {
condition = StringUtils.quoteRemarkSQL(condition); condition = StringUtils.quoteRemarkSQL(condition);
buff.append(condition).append(" */"); buff.append(condition).append(" */");
} }
if (scanCount > 0) {
buff.append(" /* scanCount: ").append(scanCount).append(" */");
}
return buff.toString(); return buff.toString();
} }
......
...@@ -2511,8 +2511,8 @@ insert into x values(0), (1), (10); ...@@ -2511,8 +2511,8 @@ insert into x values(0), (1), (10);
> update count: 3 > update count: 3
SELECT t1.ID, (SELECT t1.id || ':' || AVG(t2.ID) FROM X t2) FROM X t1; SELECT t1.ID, (SELECT t1.id || ':' || AVG(t2.ID) FROM X t2) FROM X t1;
> ID SELECT ((T1.ID || ':') || AVG(T2.ID)) FROM PUBLIC.X T2 /* PUBLIC.X.tableScan */ > ID SELECT ((T1.ID || ':') || AVG(T2.ID)) FROM PUBLIC.X T2 /* PUBLIC.X.tableScan */ /* scanCount: 4 */
> -- ------------------------------------------------------------------------------- > -- --------------------------------------------------------------------------------------------------
> 0 0:3 > 0 0:3
> 1 1:3 > 1 1:3
> 10 10:3 > 10 10:3
...@@ -2522,8 +2522,8 @@ drop table x; ...@@ -2522,8 +2522,8 @@ drop table x;
> ok > ok
select (select t1.x from system_range(1,1) t2) from system_range(1,1) t1; select (select t1.x from system_range(1,1) t2) from system_range(1,1) t1;
> SELECT T1.X FROM SYSTEM_RANGE(1, 1) T2 /* PUBLIC.RANGE_INDEX */ > SELECT T1.X FROM SYSTEM_RANGE(1, 1) T2 /* PUBLIC.RANGE_INDEX */ /* scanCount: 2 */
> --------------------------------------------------------------- > ----------------------------------------------------------------------------------
> 1 > 1
> rows: 1 > rows: 1
...@@ -3212,8 +3212,8 @@ call /* remark * / * /* ** // end */ 1; ...@@ -3212,8 +3212,8 @@ call /* remark * / * /* ** // end */ 1;
> rows: 1 > rows: 1
call (select x from dual where x is null); call (select x from dual where x is null);
> SELECT X FROM SYSTEM_RANGE(1, 1) /* PUBLIC.RANGE_INDEX */ WHERE X IS NULL > SELECT X FROM SYSTEM_RANGE(1, 1) /* PUBLIC.RANGE_INDEX */ /* scanCount: 2 */ WHERE X IS NULL
> ------------------------------------------------------------------------- > --------------------------------------------------------------------------------------------
> null > null
> rows: 1 > rows: 1
...@@ -3311,14 +3311,14 @@ insert into test values(1, 'Y'); ...@@ -3311,14 +3311,14 @@ insert into test values(1, 'Y');
> update count: 1 > update count: 1
call select a from test order by id; call select a from test order by id;
> SELECT A FROM PUBLIC.TEST /* PUBLIC.PRIMARY_KEY_2 */ ORDER BY =ID /* index sorted */ > SELECT A FROM PUBLIC.TEST /* PUBLIC.PRIMARY_KEY_2 */ /* scanCount: 2 */ ORDER BY =ID /* index sorted */
> ------------------------------------------------------------------------------------ > -------------------------------------------------------------------------------------------------------
> TRUE > TRUE
> rows (ordered): 1 > rows (ordered): 1
select select a from test order by id; select select a from test order by id;
> SELECT A FROM PUBLIC.TEST /* PUBLIC.PRIMARY_KEY_2 */ ORDER BY =ID /* index sorted */ > SELECT A FROM PUBLIC.TEST /* PUBLIC.PRIMARY_KEY_2 */ /* scanCount: 2 */ ORDER BY =ID /* index sorted */
> ------------------------------------------------------------------------------------ > -------------------------------------------------------------------------------------------------------
> TRUE > TRUE
> rows (ordered): 1 > rows (ordered): 1
...@@ -6688,19 +6688,19 @@ SELECT * FROM TEST T WHERE T.ID = (SELECT T2.ID FROM TEST T2 WHERE T2.ID=T.ID); ...@@ -6688,19 +6688,19 @@ SELECT * FROM TEST T WHERE T.ID = (SELECT T2.ID FROM TEST T2 WHERE T2.ID=T.ID);
> rows: 3 > rows: 3
SELECT (SELECT T2.NAME FROM TEST T2 WHERE T2.ID=T.ID), T.NAME FROM TEST T; SELECT (SELECT T2.NAME FROM TEST T2 WHERE T2.ID=T.ID), T.NAME FROM TEST T;
> SELECT T2.NAME FROM PUBLIC.TEST T2 /* PUBLIC.PRIMARY_KEY_2: ID = T.ID */ WHERE T2.ID = T.ID NAME > SELECT T2.NAME FROM PUBLIC.TEST T2 /* PUBLIC.PRIMARY_KEY_2: ID = T.ID */ /* scanCount: 2 */ WHERE T2.ID = T.ID NAME
> ------------------------------------------------------------------------------------------- ----- > -------------------------------------------------------------------------------------------------------------- -----
> Hello Hello > Hello Hello
> World World > World World
> null null > null null
> rows: 3 > rows: 3
SELECT (SELECT SUM(T2.ID) FROM TEST T2 WHERE T2.ID>T.ID), T.ID FROM TEST T; SELECT (SELECT SUM(T2.ID) FROM TEST T2 WHERE T2.ID>T.ID), T.ID FROM TEST T;
> SELECT SUM(T2.ID) FROM PUBLIC.TEST T2 /* PUBLIC.PRIMARY_KEY_2: ID > T.ID */ WHERE T2.ID > T.ID ID > SELECT SUM(T2.ID) FROM PUBLIC.TEST T2 /* PUBLIC.PRIMARY_KEY_2: ID > T.ID */ /* scanCount: 2 */ WHERE T2.ID > T.ID ID
> ---------------------------------------------------------------------------------------------- -- > ----------------------------------------------------------------------------------------------------------------- --
> 2 1 > 2 1
> 3 0 > 3 0
> null 2 > null 2
> rows: 3 > rows: 3
select * from test t where t.id+1 in (select id from test); select * from test t where t.id+1 in (select id from test);
......
Markdown 格式
0%
您添加了 0 到此讨论。请谨慎行事。
请先完成此评论的编辑!
注册 或者 后发表评论