提交 63093d87 authored 作者: Thomas Mueller's avatar Thomas Mueller

The index was not used if there were multiple IN(..) conditions.

上级 be2326c6
...@@ -6,6 +6,7 @@ ...@@ -6,6 +6,7 @@
*/ */
package org.h2.index; package org.h2.index;
import java.util.ArrayList;
import java.util.Arrays; import java.util.Arrays;
import java.util.Comparator; import java.util.Comparator;
import java.util.HashSet; import java.util.HashSet;
...@@ -206,10 +207,10 @@ public class IndexCondition { ...@@ -206,10 +207,10 @@ public class IndexCondition {
/** /**
* Get the comparison bit mask. * Get the comparison bit mask.
* *
* @param conditionCount the number of index conditions * @param indexConditions all index conditions
* @return the mask * @return the mask
*/ */
public int getMask(int conditionCount) { public int getMask(ArrayList<IndexCondition> indexConditions) {
switch (compareType) { switch (compareType) {
case Comparison.FALSE: case Comparison.FALSE:
return ALWAYS_FALSE; return ALWAYS_FALSE;
...@@ -217,11 +218,30 @@ public class IndexCondition { ...@@ -217,11 +218,30 @@ public class IndexCondition {
return EQUALITY; return EQUALITY;
case Comparison.IN_LIST: case Comparison.IN_LIST:
case Comparison.IN_QUERY: case Comparison.IN_QUERY:
if (conditionCount > 1) { if (indexConditions.size() > 1) {
// if there are more conditions, don't use the index on IN(..) // IN(..) can not be combined with other conditions.
// IN(..) can not be combined with other conditions, // If there are other conditions (except for other
// otherwise the query returns the wrong result // IN_ conditions), don't use the index on IN(..)
return 0; // otherwise the query returns the wrong result.
boolean beforeThis = true;
for (IndexCondition c : indexConditions) {
if (c == this) {
beforeThis = false;
continue;
}
if (c.isEvaluatable()) {
if (beforeThis) {
// If there are only multiple IN_ conditions,
// only the first one can be used
return 0;
}
if (!c.isIn()) {
// If there are other (non-IN_) conditions,
// this one can't be used
return 0;
}
}
}
} }
return EQUALITY; return EQUALITY;
case Comparison.BIGGER_EQUAL: case Comparison.BIGGER_EQUAL:
...@@ -244,6 +264,16 @@ public class IndexCondition { ...@@ -244,6 +264,16 @@ public class IndexCondition {
return compareType == Comparison.FALSE; return compareType == Comparison.FALSE;
} }
private boolean isIn() {
switch (compareType) {
case Comparison.IN_LIST:
case Comparison.IN_QUERY:
return true;
default:
return false;
}
}
/** /**
* Check if this index condition is of the type column larger or equal to * Check if this index condition is of the type column larger or equal to
* value. * value.
......
...@@ -22,7 +22,7 @@ SELECT COUNT(*) FROM TEST; ...@@ -22,7 +22,7 @@ SELECT COUNT(*) FROM TEST;
-- Display the query plan - 'direct lookup' means the index is used -- Display the query plan - 'direct lookup' means the index is used
EXPLAIN SELECT COUNT(*) FROM TEST; EXPLAIN SELECT COUNT(*) FROM TEST;
--> SELECT COUNT(*) --> SELECT COUNT(*)
--> FROM PUBLIC.TEST /* PUBLIC.TEST_DATA */ --> FROM PUBLIC.TEST /* PUBLIC.TEST.tableScan */
--> /* direct lookup */ --> /* direct lookup */
; ;
...@@ -90,7 +90,7 @@ SELECT MIN(VALUE), MAX(VALUE) FROM TEST; ...@@ -90,7 +90,7 @@ SELECT MIN(VALUE), MAX(VALUE) FROM TEST;
-- Display the query plan - 'direct lookup' means it's optimized -- Display the query plan - 'direct lookup' means it's optimized
EXPLAIN SELECT MIN(VALUE), MAX(VALUE) FROM TEST; EXPLAIN SELECT MIN(VALUE), MAX(VALUE) FROM TEST;
--> SELECT MIN(VALUE), MAX(VALUE) --> SELECT MIN(VALUE), MAX(VALUE)
--> FROM PUBLIC.TEST /* PUBLIC.TEST_DATA */ --> FROM PUBLIC.TEST /* PUBLIC.TEST.tableScan */
--> /* direct lookup */ --> /* direct lookup */
; ;
...@@ -223,3 +223,22 @@ EXPLAIN SELECT * FROM TEST WHERE ID IN(1, 1000); ...@@ -223,3 +223,22 @@ EXPLAIN SELECT * FROM TEST WHERE ID IN(1, 1000);
DROP TABLE TEST; DROP TABLE TEST;
-------------------------------------------------------------------------------
-- Optimize Multiple IN(..)
-------------------------------------------------------------------------------
-- This code snippet shows how multiple IN(...) conditions use an index.
-- Initialize the data
CREATE TABLE TEST(ID INT PRIMARY KEY, DATA INT);
CREATE INDEX TEST_DATA ON TEST(DATA);
INSERT INTO TEST SELECT X, MOD(X, 10) FROM SYSTEM_RANGE(1, 1000);
-- Display the query plan
EXPLAIN SELECT * FROM TEST WHERE ID IN (10, 20) AND DATA IN (1, 2);
--> SELECT TEST.ID, TEST.DATA
--> FROM PUBLIC.TEST /* PUBLIC.PRIMARY_KEY_2: ID IN(10, 20) */
--> WHERE (ID IN(10, 20)) AND (DATA IN(1, 2))
;
DROP TABLE TEST;
Markdown 格式
0%
您添加了 0 到此讨论。请谨慎行事。
请先完成此评论的编辑!
注册 或者 后发表评论