Skip to content

Commit

Permalink
Merge pull request h2database#4117 from katzyn/plan
Browse files Browse the repository at this point in the history
Fix Index.getCostRangeIndex()
  • Loading branch information
katzyn authored Aug 15, 2024
2 parents 72ced0f + a626be4 commit d947b59
Show file tree
Hide file tree
Showing 3 changed files with 75 additions and 12 deletions.
2 changes: 2 additions & 0 deletions h2/src/docsrc/html/changelog.html
Original file line number Diff line number Diff line change
Expand Up @@ -21,6 +21,8 @@ <h1>Change Log</h1>

<h2>Next Version (unreleased)</h2>
<ul>
<li>Issue #4116: Optimizer chooses wrong execution plan in some cases when index-sorted optimization is possible
</li>
<li>Issue #4114: Regression when using CAST expressions in ROW IN predicates
</li>
<li>Issue #4111: ALTER TYPE name ADD VALUE new_enum_value is not supported
Expand Down
49 changes: 37 additions & 12 deletions h2/src/main/org/h2/index/Index.java
Original file line number Diff line number Diff line change
Expand Up @@ -16,6 +16,7 @@
import org.h2.engine.SessionLocal;
import org.h2.message.DbException;
import org.h2.message.Trace;
import org.h2.mode.DefaultNullOrdering;
import org.h2.result.Row;
import org.h2.result.RowFactory;
import org.h2.result.SearchRow;
Expand Down Expand Up @@ -621,12 +622,14 @@ protected final long getCostRangeIndex(int[] masks, long rowCount, TableFilter[]
if (sortOrder != null) {
sortingCost = 100 + rowCount / 10;
}
if (sortOrder != null && !isScanIndex) {
boolean sortOrderMatches = true;
if (sortOrder != null && !isScanIndex && filters != null && filter == 0) {
int coveringCount = 0;
int[] sortTypes = sortOrder.getSortTypesWithNullOrdering();
TableFilter tableFilter = filters == null ? null : filters[filter];
for (int i = 0, len = sortTypes.length; i < len; i++) {
int sortOrderLength = sortTypes.length;
TableFilter tableFilter = filters[0];
DefaultNullOrdering defaultNullOrdering = getDatabase().getDefaultNullOrdering();
boolean reverse = false;
for (int i = 0; i < sortOrderLength; i++) {
if (i >= indexColumns.length) {
// We can still use this index if we are sorting by more
// than it's columns, it's just that the coveringCount
Expand All @@ -636,22 +639,44 @@ protected final long getCostRangeIndex(int[] masks, long rowCount, TableFilter[]
}
Column col = sortOrder.getColumn(i, tableFilter);
if (col == null) {
sortOrderMatches = false;
break;
}
IndexColumn indexCol = indexColumns[i];
if (!col.equals(indexCol.column)) {
sortOrderMatches = false;
IndexColumn idxCol = indexColumns[i];
if (!col.equals(idxCol.column)) {
break;
}
int sortType = sortTypes[i];
if (sortType != indexCol.sortType) {
sortOrderMatches = false;
boolean mismatch = false;
if (col.isNullable()) {
int o1 = defaultNullOrdering.addExplicitNullOrdering(idxCol.sortType);
int o2 = sortTypes[i];
if (i == 0) {
if (o1 != o2) {
if (o1 == SortOrder.inverse(o2)) {
reverse = true;
} else {
mismatch = true;
}
}
} else {
if (o1 != (reverse ? SortOrder.inverse(o2) : o2)) {
mismatch = true;
}
}
} else {
boolean different = (idxCol.sortType & SortOrder.DESCENDING) //
!= (sortTypes[i] & SortOrder.DESCENDING);
if (i == 0) {
reverse = different;
} else {
mismatch = different != reverse;
}
}
if (mismatch) {
break;
}
coveringCount++;
}
if (sortOrderMatches) {
if (coveringCount > 0) {
// "coveringCount" makes sure that when we have two
// or more covering indexes, we choose the one
// that covers more.
Expand Down
36 changes: 36 additions & 0 deletions h2/src/test/org/h2/test/scripts/indexes.sql
Original file line number Diff line number Diff line change
Expand Up @@ -1239,3 +1239,39 @@ SELECT _ROWID_, * FROM TEST ORDER BY _ROWID_ DESC;

DROP TABLE TEST;
> ok

CREATE TABLE TEST(C INT PRIMARY KEY);
> ok

EXPLAIN SELECT * FROM TEST A JOIN TEST B USING(C) ORDER BY A.C ASC FETCH FIRST 10 ROWS ONLY;
>> SELECT "A"."C" FROM "PUBLIC"."TEST" "A" /* PUBLIC.PRIMARY_KEY_2 */ INNER JOIN "PUBLIC"."TEST" "B" /* PUBLIC.PRIMARY_KEY_2: C = A.C */ ON 1=1 WHERE "A"."C" = "B"."C" ORDER BY 1 FETCH FIRST 10 ROWS ONLY /* index sorted */

EXPLAIN SELECT * FROM TEST A JOIN TEST B USING(C) ORDER BY A.C DESC FETCH FIRST 10 ROWS ONLY;
>> SELECT "A"."C" FROM "PUBLIC"."TEST" "A" /* PUBLIC.PRIMARY_KEY_2 */ INNER JOIN "PUBLIC"."TEST" "B" /* PUBLIC.PRIMARY_KEY_2: C = A.C */ ON 1=1 WHERE "A"."C" = "B"."C" ORDER BY 1 DESC FETCH FIRST 10 ROWS ONLY /* index sorted */

DROP TABLE TEST;
> ok

CREATE TABLE TEST(C INT UNIQUE);
> ok

EXPLAIN SELECT * FROM TEST A JOIN TEST B USING(C) ORDER BY A.C ASC FETCH FIRST 10 ROWS ONLY;
>> SELECT "A"."C" FROM "PUBLIC"."TEST" "A" /* PUBLIC.CONSTRAINT_INDEX_2 */ INNER JOIN "PUBLIC"."TEST" "B" /* PUBLIC.CONSTRAINT_INDEX_2: C = A.C */ ON 1=1 WHERE "A"."C" = "B"."C" ORDER BY 1 FETCH FIRST 10 ROWS ONLY /* index sorted */

EXPLAIN SELECT * FROM TEST A JOIN TEST B USING(C) ORDER BY A.C DESC FETCH FIRST 10 ROWS ONLY;
>> SELECT "A"."C" FROM "PUBLIC"."TEST" "A" /* PUBLIC.CONSTRAINT_INDEX_2 */ INNER JOIN "PUBLIC"."TEST" "B" /* PUBLIC.CONSTRAINT_INDEX_2: C = A.C */ ON 1=1 WHERE "A"."C" = "B"."C" ORDER BY 1 DESC FETCH FIRST 10 ROWS ONLY /* index sorted */

DROP TABLE TEST;
> ok

CREATE TABLE TEST(X INT, Y INT, UNIQUE(X, Y));
> ok

EXPLAIN SELECT * FROM TEST A JOIN TEST B USING(X, Y) ORDER BY A.X, A.Y FETCH FIRST 10 ROWS ONLY;
>> SELECT "A"."X", "A"."Y" FROM "PUBLIC"."TEST" "A" /* PUBLIC.CONSTRAINT_INDEX_2 */ INNER JOIN "PUBLIC"."TEST" "B" /* PUBLIC.CONSTRAINT_INDEX_2: X = A.X AND Y = A.Y */ ON 1=1 WHERE ("A"."X" = "B"."X") AND ("A"."Y" = "B"."Y") ORDER BY 1, 2 FETCH FIRST 10 ROWS ONLY /* index sorted */

EXPLAIN SELECT * FROM TEST A JOIN TEST B USING(X, Y) ORDER BY A.X DESC, A.Y FETCH FIRST 10 ROWS ONLY;
>> SELECT "A"."X", "A"."Y" FROM "PUBLIC"."TEST" "A" /* PUBLIC.CONSTRAINT_INDEX_2 */ INNER JOIN "PUBLIC"."TEST" "B" /* PUBLIC.CONSTRAINT_INDEX_2: X = A.X AND Y = A.Y */ ON 1=1 WHERE ("A"."X" = "B"."X") AND ("A"."Y" = "B"."Y") ORDER BY 1 DESC, 2 FETCH FIRST 10 ROWS ONLY /* index sorted: 1 of 2 columns */

DROP TABLE TEST;
> ok

0 comments on commit d947b59

Please sign in to comment.