提交 b2ef093c authored 作者: Steve McLeod's avatar Steve McLeod 提交者: Sergi Vladykin

Add index hints (#425)

* Added parsing of table hints

* Implemented USE INDEX hints

* Added docs, tidied up code for submission

* Added docs, tidied up code for submission

* Removed used of final static field that would cause problems with Tomcat class unloading

* Removed used of final static field that would cause problems with Tomcat class unloading

* A table with no index hints now has indexHints == null, instead of an employ instance of IndexHints. For the common case of no index hints, this will prevent some unnecessary object creation.

* Index Hints now is backward compatible with using the "USE" as a table alias

* Added TestIndexHints to list of all tests

* Added index hints to text generated by TableFilter.getPlanSQL();

* Improved field names (a field called indexList was actually a set);
Added test for ensuring getPlanSQL lists index hints in correct order

* Improved unit test for making sure getPlanSQL renders index hints list in correct order
上级 b35d4c84
......@@ -2141,6 +2141,7 @@ ID + 20
"Other Grammar","Table Expression","
{ [ schemaName. ] tableName | ( select ) | valuesExpression } [ [ AS ] newTableAlias ]
[ USE INDEX ([ indexName [,...] ]) ]
[ { { LEFT | RIGHT } [ OUTER ] | [ INNER ] | CROSS | NATURAL }
JOIN tableExpression [ ON expression ] ]
","
......
......@@ -21,6 +21,8 @@ Change Log
<h2>Next Version (unreleased)</h2>
<ul>
<li>Added index hints: SELECT * FROM TEST USE INDEX (idx1, idx2)
</li>
<li>Add a test case to ensure that spatial index is used with and order by command by Fortin N
</li>
<li>Fix multi-threaded mode update exception "NullPointerException", test case by Anatolii K
......
......@@ -371,6 +371,22 @@ Indexes are also created for foreign key constraints, if required.
For other columns, indexes need to be created manually using the <code>CREATE INDEX</code> statement.
</p>
<h3>Index Hints</h3>
<p>
If you have determined that H2 is not using the optimal index for your query, you can use index hints to force
H2 to use specific indexes.
</p>
<pre>
SELECT * FROM TEST USE INDEX (index_name_1, index_name_2) WHERE X=1
</pre>
<p>Only indexes in the list will be used when choosing an index to use on the given table. There
is no significance to order in this list.
</p><p>
It is possible that no index in the list is chosen, in which case a full table scan will be used.
</p>
<p>An empty list of index names forces a full table scan to be performed.</p>
<p>Each index in the list must exist.</p>
<h3>How Data is Stored Internally</h3>
<p>
For persistent databases, if a table is created with a single column primary key of type <code>BIGINT, INT, SMALLINT, TINYINT</code>,
......
......@@ -16,6 +16,7 @@ import java.util.ArrayList;
import java.util.Collections;
import java.util.Comparator;
import java.util.HashSet;
import java.util.LinkedHashSet;
import org.h2.api.ErrorCode;
import org.h2.api.Trigger;
import org.h2.command.ddl.AlterIndexRename;
......@@ -128,6 +129,7 @@ import org.h2.schema.Sequence;
import org.h2.table.Column;
import org.h2.table.FunctionTable;
import org.h2.table.IndexColumn;
import org.h2.table.IndexHints;
import org.h2.table.RangeTable;
import org.h2.table.Table;
import org.h2.table.TableFilter;
......@@ -795,7 +797,7 @@ public class Parser {
}
}
return new TableFilter(session, table, alias, rightsChecked,
currentSelect, orderInFrom);
currentSelect, orderInFrom, null);
}
private Delete parseDelete() {
......@@ -1257,9 +1259,41 @@ public class Parser {
table = readTableOrView(tableName);
}
}
IndexHints indexHints = null;
// for backward compatibility, handle case where USE is a table alias
if (readIf("USE")) {
if (readIf("INDEX")) {
indexHints = parseUseIndexList();
} else {
alias = "USE";
}
} else {
alias = readFromAlias(alias);
if (alias != null) {
// if alias present, a second chance to parse index hints
if (readIf("USE")) {
read("INDEX");
indexHints = parseUseIndexList();
}
}
}
return new TableFilter(session, table, alias, rightsChecked,
currentSelect, orderInFrom++);
currentSelect, orderInFrom++, indexHints);
}
private IndexHints parseUseIndexList() {
read("(");
LinkedHashSet<String> indexNames = new LinkedHashSet<>();
if (!readIf(")")) {
do {
indexNames.add(readIdentifierWithSchema());
} while (readIf(","));
read(")");
}
return IndexHints.createUseIndexHints(indexNames);
}
private String readFromAlias(String alias) {
......@@ -1633,7 +1667,8 @@ public class Parser {
private TableFilter getNested(TableFilter n) {
String joinTable = Constants.PREFIX_JOIN + parseIndex;
TableFilter top = new TableFilter(session, getDualTable(true),
joinTable, rightsChecked, currentSelect, n.getOrderInFrom());
joinTable, rightsChecked, currentSelect, n.getOrderInFrom(),
null);
top.addJoin(n, false, true, null);
return top;
}
......@@ -2039,7 +2074,8 @@ public class Parser {
// SYSTEM_RANGE(1,1)
Table dual = getDualTable(false);
TableFilter filter = new TableFilter(session, dual, null,
rightsChecked, currentSelect, 0);
rightsChecked, currentSelect, 0,
null);
command.addTableFilter(filter, true);
} else {
parseSelectSimpleFromPart(command);
......@@ -4486,7 +4522,8 @@ public class Parser {
tf.doneWithParameters();
Table table = new FunctionTable(mainSchema, session, tf, tf);
TableFilter filter = new TableFilter(session, table, null,
rightsChecked, currentSelect, orderInFrom);
rightsChecked, currentSelect, orderInFrom,
null);
return filter;
}
......
......@@ -186,7 +186,7 @@ public class AlterTableAddConstraint extends SchemaCommand {
int id = getObjectId();
String name = generateConstraintName(table);
ConstraintCheck check = new ConstraintCheck(getSchema(), id, name, table);
TableFilter filter = new TableFilter(session, table, null, false, null, 0);
TableFilter filter = new TableFilter(session, table, null, false, null, 0, null);
checkExpression.mapColumns(filter, 0);
checkExpression = checkExpression.optimize(session);
check.setExpression(checkExpression);
......
......@@ -705,6 +705,7 @@ factor [ { { + | - } factor } [...] ]
A value or a numeric sum."
"Other Grammar","Table Expression","
{ [ schemaName. ] tableName | ( select ) | valuesExpression } [ [ AS ] newTableAlias ]
[ USE INDEX ([ indexName [,...] ]) ]
[ { { LEFT | RIGHT } [ OUTER ] | [ INNER ] | CROSS | NATURAL }
JOIN tableExpression [ ON expression ] ]
","
......
......@@ -405,7 +405,8 @@ public class Column {
*/
public void prepareExpression(Session session) {
if (defaultExpression != null) {
computeTableFilter = new TableFilter(session, table, null, false, null, 0);
computeTableFilter = new TableFilter(session, table, null, false, null, 0,
null);
defaultExpression.mapColumns(computeTableFilter, 0);
defaultExpression = defaultExpression.optimize(session);
}
......
/*
* Copyright 2004-2014 H2 Group. Multiple-Licensed under the MPL 2.0,
* and the EPL 1.0 (http://h2database.com/html/license.html).
* Initial Developer: H2 Group
*/
package org.h2.table;
import org.h2.index.Index;
import java.util.LinkedHashSet;
import java.util.Set;
/**
* Contains the hints for which index to use for a specific table. Currently
* allows a list of "use indexes" to be specified.
* <p>
* Use the factory method IndexHints.createUseIndexHints(listOfIndexes) to limit
* the query planner to only use specific indexes when determining which index
* to use for a table
**/
public final class IndexHints {
private final LinkedHashSet<String> allowedIndexes;
private IndexHints(LinkedHashSet<String> allowedIndexes) {
this.allowedIndexes = allowedIndexes;
}
public static IndexHints createUseIndexHints(LinkedHashSet<String> allowedIndexes) {
return new IndexHints(allowedIndexes);
}
public Set<String> getAllowedIndexes() {
return allowedIndexes;
}
@Override
public String toString() {
return "IndexHints{allowedIndexes=" + allowedIndexes + '}';
}
public boolean allowIndex(Index index) {
return allowedIndexes.contains(index.getName());
}
}
......@@ -693,9 +693,16 @@ public abstract class Table extends SchemaObjectBase {
item.cost, item.getIndex().getPlanSQL());
}
ArrayList<Index> indexes = getIndexes();
IndexHints indexHints = getIndexHints(session, filters, filter);
if (indexes != null && masks != null) {
for (int i = 1, size = indexes.size(); i < size; i++) {
Index index = indexes.get(i);
if (isIndexExcludedByHints(indexHints, index)) {
continue;
}
double cost = index.getCost(session, masks, filters, filter,
sortOrder, allColumnsSet);
if (t.isDebugEnabled()) {
......@@ -711,6 +718,29 @@ public abstract class Table extends SchemaObjectBase {
return item;
}
private boolean isIndexExcludedByHints(IndexHints indexHints, Index index) {
return indexHints != null && !indexHints.allowIndex(index);
}
private IndexHints getIndexHints(Session session, TableFilter[] filters, int filter) {
if (filters == null) {
return null;
}
IndexHints indexHints = filters[filter].getIndexHints();
if (indexHints == null) {
return null;
}
// check all index names in hints are valid indexes
for (String indexName : indexHints.getAllowedIndexes()) {
Index index = getSchema().findIndex(session, indexName);
if (index == null) {
throw DbException.get(ErrorCode.INDEX_NOT_FOUND_1, indexName);
}
}
return indexHints;
}
/**
* Get the primary key index if there is one, or null if there is none.
*
......
......@@ -55,6 +55,7 @@ public class TableFilter implements ColumnResolver {
private final Select select;
private String alias;
private Index index;
private final IndexHints indexHints;
private int[] masks;
private int scanCount;
private boolean evaluatable;
......@@ -125,10 +126,10 @@ public class TableFilter implements ColumnResolver {
* @param rightsChecked true if rights are already checked
* @param select the select statement
* @param orderInFrom original order number (index) of this table filter in
* FROM clause (0, 1, 2,...)
* @param indexHints the index hints to be used by the query planner
*/
public TableFilter(Session session, Table table, String alias,
boolean rightsChecked, Select select, int orderInFrom) {
boolean rightsChecked, Select select, int orderInFrom, IndexHints indexHints) {
this.session = session;
this.table = table;
this.alias = alias;
......@@ -139,6 +140,7 @@ public class TableFilter implements ColumnResolver {
}
hashCode = session.nextObjectId();
this.orderInFrom = orderInFrom;
this.indexHints = indexHints;
}
/**
......@@ -827,6 +829,19 @@ public class TableFilter implements ColumnResolver {
if (alias != null) {
buff.append(' ').append(Parser.quoteIdentifier(alias));
}
if (indexHints != null) {
buff.append(" USE INDEX (");
boolean first = true;
for (String index : indexHints.getAllowedIndexes()) {
if (!first) {
buff.append(", ");
} else {
first = false;
}
buff.append(index);
}
buff.append(")");
}
if (index != null) {
buff.append('\n');
StatementBuilder planBuff = new StatementBuilder();
......@@ -1193,6 +1208,10 @@ public class TableFilter implements ColumnResolver {
return session;
}
public IndexHints getIndexHints() {
return indexHints;
}
/**
* A visitor for table filters.
*/
......
......@@ -37,6 +37,7 @@ import org.h2.test.db.TestFullText;
import org.h2.test.db.TestFunctionOverload;
import org.h2.test.db.TestFunctions;
import org.h2.test.db.TestIndex;
import org.h2.test.db.TestIndexHints;
import org.h2.test.db.TestLargeBlob;
import org.h2.test.db.TestLinkedTable;
import org.h2.test.db.TestListener;
......@@ -707,6 +708,7 @@ kill -9 `jps -l | grep "org.h2.test." | cut -d " " -f 1`
addTest(new TestFunctions());
addTest(new TestInit());
addTest(new TestIndex());
addTest(new TestIndexHints());
addTest(new TestLargeBlob());
addTest(new TestLinkedTable());
addTest(new TestListener());
......
/*
* Copyright 2004-2017 H2 Group. Multiple-Licensed under the MPL 2.0,
* and the EPL 1.0 (http://h2database.com/html/license.html).
* Initial Developer: H2 Group
*/
package org.h2.test.db;
import org.h2.test.TestBase;
import java.sql.Connection;
import java.sql.ResultSet;
import java.sql.SQLException;
import java.sql.Statement;
/**
* Tests the index hints feature of this database.
*/
public class TestIndexHints extends TestBase {
/**
* Run just this test.
*
* @param a ignored
*/
public static void main(String... a) throws Exception {
TestBase.createCaller().init().test();
}
@Override
public void test() throws Exception {
deleteDb("indexhints");
createDb();
testWithSingleIndexName();
testWithEmptyIndexHintsList();
testWithInvalidIndexName();
testWithMultipleIndexNames();
testPlanSqlHasIndexesInCorrectOrder();
testWithTableAlias();
testWithTableAliasCalledUse();
deleteDb("indexhints");
}
private void createDb() throws SQLException {
Connection conn = getConnection("indexhints");
Statement stat = conn.createStatement();
stat.execute("create table test (x int, y int)");
stat.execute("create index idx1 on test (x)");
stat.execute("create index idx2 on test (x, y)");
}
private void testWithSingleIndexName() throws SQLException {
Connection conn = getConnection("indexhints");
Statement stat = conn.createStatement();
ResultSet rs = stat.executeQuery("explain analyze select * " +
"from test use index(idx1) where x=1 and y=1");
rs.next();
String result = rs.getString(1);
assertTrue(result.contains("/* PUBLIC.IDX1:"));
conn.close();
}
private void testWithTableAlias() throws SQLException {
Connection conn = getConnection("indexhints");
Statement stat = conn.createStatement();
ResultSet rs = stat.executeQuery("explain analyze select * " +
"from test t use index(idx2) where x=1 and y=1");
rs.next();
String result = rs.getString(1);
assertTrue(result.contains("/* PUBLIC.IDX2:"));
conn.close();
}
private void testWithTableAliasCalledUse() throws SQLException {
// make sure that while adding new syntax for table hints, code
// that uses "USE" as a table alias still works
Connection conn = getConnection("indexhints");
Statement stat = conn.createStatement();
stat.executeQuery("explain analyze select * " +
"from test use where use.x=1 and use.y=1");
conn.close();
}
private void testWithMultipleIndexNames() throws SQLException {
Connection conn = getConnection("indexhints");
Statement stat = conn.createStatement();
ResultSet rs = stat.executeQuery("explain analyze select * " +
"from test use index(idx1, idx2) where x=1 and y=1");
rs.next();
String result = rs.getString(1);
assertTrue(result.contains("/* PUBLIC.IDX2:"));
conn.close();
}
private void testPlanSqlHasIndexesInCorrectOrder() throws SQLException {
Connection conn = getConnection("indexhints");
ResultSet rs = conn.createStatement().executeQuery("explain analyze select * " +
"from test use index(idx1, idx2) where x=1 and y=1");
rs.next();
assertTrue(rs.getString(1).contains("USE INDEX (IDX1, IDX2)"));
ResultSet rs2 = conn.createStatement().executeQuery("explain analyze select * " +
"from test use index(idx2, idx1) where x=1 and y=1");
rs2.next();
assertTrue(rs2.getString(1).contains("USE INDEX (IDX2, IDX1)"));
conn.close();
}
private void testWithEmptyIndexHintsList() throws SQLException {
Connection conn = getConnection("indexhints");
Statement stat = conn.createStatement();
ResultSet rs = stat.executeQuery("explain analyze select * " +
"from test use index () where x=1 and y=1");
rs.next();
String result = rs.getString(1);
assertTrue(result.contains("/* PUBLIC.TEST.tableScan"));
conn.close();
}
private void testWithInvalidIndexName() throws SQLException {
Connection conn = getConnection("indexhints");
Statement stat = conn.createStatement();
try {
stat.executeQuery("explain analyze select * " +
"from test use index(idx_doesnt_exist) where x=1 and y=1");
fail("Expected exception: "
+ "Index \"IDX_DOESNT_EXIST\" not found");
} catch (SQLException e) {
assert(e.getErrorCode() == 1);
} finally {
conn.close();
}
}
}
Markdown 格式
0%
您添加了 0 到此讨论。请谨慎行事。
请先完成此评论的编辑!
注册 或者 后发表评论