提交 b5da88fc authored 作者: noelgrandin@gmail.com's avatar noelgrandin@gmail.com

Make the planner use indexes for sorting when doing a GROUP BY where

all of the GROUP BY columns are not mentioned in the select. Patch by Frederico (zepfred).
上级 2f18ec4c
......@@ -34,6 +34,8 @@ Change Log
select * from dual join(select x from dual) on 1=1
</li><li>Issue 598: parser fails on timestamp "24:00:00.1234" - prevent the creation of out-of-range time values.
</li><li>Allow declaring triggers as source code (like functions). Patch by Sylvain CUAZ.
</li><li>Make the planner use indexes for sorting when doing a GROUP BY where
all of the GROUP BY columns are not mentioned in the select. Patch by Frederico (zepfred).
</li></ul>
<h2>Version 1.4.185 Beta (2015-01-16)</h2>
......
......@@ -26,6 +26,7 @@ import org.h2.expression.Parameter;
import org.h2.expression.Wildcard;
import org.h2.index.Cursor;
import org.h2.index.Index;
import org.h2.index.IndexCondition;
import org.h2.index.IndexType;
import org.h2.message.DbException;
import org.h2.result.LocalResult;
......@@ -445,11 +446,16 @@ public class Select extends Query {
// with the exact same columns
IndexColumn idxCol = indexCols[j];
Column sortCol = sortCols[j];
boolean implicitSortColumn = false;
if (idxCol.column != sortCol) {
implicitSortColumn = isSortColumnImplicit(
topTableFilter, idxCol.column);
if (!implicitSortColumn) {
ok = false;
break;
}
if (idxCol.sortType != sortTypes[j]) {
}
if (!implicitSortColumn && idxCol.sortType != sortTypes[j]) {
// NULL FIRST for ascending and NULLS LAST
// for descending would actually match the default
ok = false;
......@@ -471,6 +477,43 @@ public class Select extends Query {
return null;
}
/**
* Validates the cases where ORDER BY clause do not contains all indexed
* columns, but the related index path still would be valid for such search.
* Sometimes, the absence of a column in the ORDER BY clause does not alter the
* expected final result, and an index sorted scan could still be used.
* <pre>
* CREATE TABLE test(a, b);
* CREATE UNIQUE INDEX idx_test ON test(a, b);
* SELECT b FROM test WHERE a=22 AND b>10 order by b;
* </pre>
* More restrictive rule where one table query with indexed column
* not present in the ORDER BY clause is filtered with equality conditions
* (at least one) of type COLUMN = CONSTANT in a conjunctive fashion.
*
* @param sortColumn Column to be validated
* @return true if the column can be used implicitly, or false
* otherwise.
*/
private boolean isSortColumnImplicit(TableFilter tableFilter,
Column sortColumn) {
if (filters.size() == 1 && condition != null
&& !condition.isDisjunctive()) {
ArrayList<IndexCondition> conditions = tableFilter
.getIndexConditionsForColumn(sortColumn);
if (conditions.isEmpty()) {
return false;
}
for (IndexCondition conditionExp : conditions) {
if (!conditionExp.isEquality(true)) {
return false;
}
}
return true;
}
return false;
}
private void queryDistinct(ResultTarget result, long limitRows) {
// limitRows must be long, otherwise we get an int overflow
// if limitRows is at or near Integer.MAX_VALUE
......
......@@ -284,6 +284,11 @@ public class ConditionAndOr extends Condition {
return left.getCost() + right.getCost();
}
@Override
public boolean isDisjunctive() {
return andOrType == OR || left.isDisjunctive() || right.isDisjunctive();
}
/**
* Get the left or the right sub-expression of this condition.
*
......
......@@ -191,6 +191,11 @@ public class ConditionIn extends Condition {
return cost;
}
@Override
public boolean isDisjunctive() {
return true;
}
/**
* Add an additional element if possible. Example: given two conditions
* A IN(1, 2) OR A=3, the constant 3 is added: A IN(1, 2, 3).
......
......@@ -147,6 +147,11 @@ public class ConditionInConstantSet extends Condition {
return cost;
}
@Override
public boolean isDisjunctive() {
return true;
}
/**
* Add an additional element if possible. Example: given two conditions
* A IN(1, 2) OR A=3, the constant 3 is added: A IN(1, 2, 3).
......
......@@ -184,4 +184,8 @@ public class ConditionInSelect extends Condition {
filter.addIndexCondition(IndexCondition.getInQuery(l, query));
}
@Override
public boolean isDisjunctive() {
return true;
}
}
......@@ -262,6 +262,15 @@ public abstract class Expression {
return this;
}
/**
* Allows to check if the related expression is under conjunctive format.
*
* @return if the related expression has the logic operator OR.
*/
public boolean isDisjunctive(){
return false;
}
/**
* Add conditions to a table filter if they can be evaluated.
*
......
......@@ -332,6 +332,22 @@ public class IndexCondition {
}
}
/**
* Check if this index condition is of the type equality.
*
* @param constantExpression if the inner node is a constant expression
* @return true if this is a equality condition
*/
public boolean isEquality(boolean constantExpression){
switch (compareType) {
case Comparison.EQUAL:
case Comparison.EQUAL_NULL_SAFE:
return !constantExpression || expression.isConstant();
default:
return false;
}
}
public int getCompareType() {
return compareType;
}
......
......@@ -486,6 +486,22 @@ public class TableFilter implements ColumnResolver {
indexConditions.add(condition);
}
/**
* Return a list of index condition filtered by a specific column.
*
* @param column The column of the condition
* @return the filtered list
*/
public ArrayList<IndexCondition> getIndexConditionsForColumn(Column column){
ArrayList<IndexCondition> conditions = New.arrayList(indexConditions.size());
for (IndexCondition condition: indexConditions){
if (column.equals(condition.getColumn())){
conditions.add(condition);
}
}
return conditions;
}
/**
* Add a filter condition.
*
......
......@@ -62,6 +62,7 @@ public class TestOptimizations extends TestBase {
testNestedInSelect();
testInSelectJoin();
testMinMaxNullOptimization();
testUseIndexWhenAllColumnsNotInOrderBy();
if (config.networked) {
return;
}
......@@ -669,6 +670,22 @@ public class TestOptimizations extends TestBase {
conn.close();
}
private void testUseIndexWhenAllColumnsNotInOrderBy() throws SQLException {
deleteDb("optimizations");
Connection conn = getConnection("optimizations");
Statement stat = conn.createStatement();
stat.execute("CREATE TABLE test(id INT PRIMARY KEY, account INT, txid INT);");
stat.execute("INSERT INTO test SELECT x, x*100, x FROM SYSTEM_RANGE(1, 10000);");
stat.execute("ANALYZE SAMPLE_SIZE 5");
stat.execute("CREATE UNIQUE INDEX idx_test_account_txid ON test(account, txid DESC);");
ResultSet rs;
rs = stat.executeQuery("EXPLAIN ANALYZE SELECT txid FROM test WHERE account=22 AND txid<9999999 ORDER BY txid DESC LIMIT 25");
rs.next();
String plan = rs.getString(1);
assertContains(plan, "index sorted");
conn.close();
}
private void testDistinctOptimization() throws SQLException {
deleteDb("optimizations");
Connection conn = getConnection("optimizations");
......
Markdown 格式
0%
您添加了 0 到此讨论。请谨慎行事。
请先完成此评论的编辑!
注册 或者 后发表评论