Skip to content

Commit

Permalink
Merge pull request #3763 from katzyn/row-value-comparion-index-condit…
Browse files Browse the repository at this point in the history
…ions

Create some index conditions for comparisons with row values
  • Loading branch information
katzyn committed Mar 22, 2023
2 parents d8af652 + f051dcd commit 55797e5
Show file tree
Hide file tree
Showing 8 changed files with 250 additions and 32 deletions.
2 changes: 2 additions & 0 deletions h2/src/docsrc/html/changelog.html
Expand Up @@ -21,6 +21,8 @@ <h1>Change Log</h1>

<h2>Next Version (unreleased)</h2>
<ul>
<li>Issue #3762: Comparison predicates with row values don't create index conditions
</li>
<li>PR #3761: LAST_DAY function and other changes
</li>
<li>Issue #3705: Oracle DATE type: milliseconds (second fractions) rounded in H2 but truncated in Oracle (fixed in SYSDATE only)
Expand Down
73 changes: 70 additions & 3 deletions h2/src/main/org/h2/expression/condition/Comparison.java
Expand Up @@ -9,6 +9,7 @@
import org.h2.engine.SessionLocal;
import org.h2.expression.Expression;
import org.h2.expression.ExpressionColumn;
import org.h2.expression.ExpressionList;
import org.h2.expression.ExpressionVisitor;
import org.h2.expression.Parameter;
import org.h2.expression.TypedValueExpression;
Expand All @@ -25,6 +26,7 @@
import org.h2.value.Value;
import org.h2.value.ValueBoolean;
import org.h2.value.ValueNull;
import org.h2.value.ValueRow;

/**
* Example comparison expressions are ID=1, NAME=NAME, NAME IS NULL.
Expand Down Expand Up @@ -394,9 +396,26 @@ public void createIndexConditions(SessionLocal session, TableFilter filter) {
}

static void createIndexConditions(TableFilter filter, Expression left, Expression right, int compareType) {
if (compareType == NOT_EQUAL || compareType == NOT_EQUAL_NULL_SAFE) {
return;
}
if (!filter.getTable().isQueryComparable()) {
return;
}
if (compareType != SPATIAL_INTERSECTS) {
boolean lIsList = left instanceof ExpressionList, rIsList = right instanceof ExpressionList;
if (lIsList) {
if (rIsList) {
createIndexConditions(filter, (ExpressionList) left, (ExpressionList) right, compareType);
} else if (right instanceof ValueExpression) {
createIndexConditions(filter, (ExpressionList) left, (ValueExpression) right, compareType);
}
} else if (rIsList && left instanceof ValueExpression) {
createIndexConditions(filter, (ExpressionList) right, (ValueExpression) left,
getReversedCompareType(compareType));
return;
}
}
ExpressionColumn l = null;
if (left instanceof ExpressionColumn) {
l = (ExpressionColumn) left;
Expand Down Expand Up @@ -425,9 +444,6 @@ static void createIndexConditions(TableFilter filter, Expression left, Expressio
}
}
switch (compareType) {
case NOT_EQUAL:
case NOT_EQUAL_NULL_SAFE:
break;
case EQUAL:
case EQUAL_NULL_SAFE:
case BIGGER:
Expand All @@ -453,6 +469,57 @@ static void createIndexConditions(TableFilter filter, Expression left, Expressio
}
}

private static void createIndexConditions(TableFilter filter, ExpressionList left, ExpressionList right,
int compareType) {
int c = left.getSubexpressionCount();
if (c == 0 || c != right.getSubexpressionCount()) {
return;
}
if (compareType != EQUAL && compareType != EQUAL_NULL_SAFE) {
if (c > 1) {
if (compareType == BIGGER) {
compareType = BIGGER_EQUAL;
} else if (compareType == SMALLER) {
compareType = SMALLER_EQUAL;
}
}
c = 1;
}
for (int i = 0; i < c; i++) {
createIndexConditions(filter, left.getSubexpression(i), right.getSubexpression(i), compareType);
}
}

private static void createIndexConditions(TableFilter filter, ExpressionList left, ValueExpression right,
int compareType) {
int c = left.getSubexpressionCount();
if (c == 0) {
return;
} else if (c == 1) {
createIndexConditions(filter, left.getSubexpression(0), right, compareType);
} else if (c > 1) {
Value v = right.getValue(null);
if (v.getValueType() == Value.ROW) {
Value[] values = ((ValueRow) v).getList();
if (c != values.length) {
return;
}
if (compareType != EQUAL && compareType != EQUAL_NULL_SAFE) {
if (compareType == BIGGER) {
compareType = BIGGER_EQUAL;
} else if (compareType == SMALLER) {
compareType = SMALLER_EQUAL;
}
c = 1;
}
for (int i = 0; i < c; i++) {
createIndexConditions(filter, left.getSubexpression(i), ValueExpression.get(values[i]),
compareType);
}
}
}
}

@Override
public void setEvaluatable(TableFilter tableFilter, boolean b) {
left.setEvaluatable(tableFilter, b);
Expand Down
70 changes: 58 additions & 12 deletions h2/src/main/org/h2/expression/condition/ConditionIn.java
Expand Up @@ -9,6 +9,7 @@
import org.h2.engine.SessionLocal;
import org.h2.expression.Expression;
import org.h2.expression.ExpressionColumn;
import org.h2.expression.ExpressionList;
import org.h2.expression.ExpressionVisitor;
import org.h2.expression.Parameter;
import org.h2.expression.TypedValueExpression;
Expand All @@ -20,6 +21,7 @@
import org.h2.value.Value;
import org.h2.value.ValueBoolean;
import org.h2.value.ValueNull;
import org.h2.value.ValueRow;

/**
* An 'in' condition with a list of values, as in WHERE NAME IN(...)
Expand Down Expand Up @@ -152,26 +154,70 @@ public Expression getNotIfPossible(SessionLocal session) {

@Override
public void createIndexConditions(SessionLocal session, TableFilter filter) {
if (not || whenOperand || !(left instanceof ExpressionColumn)) {
if (not || whenOperand || !session.getDatabase().getSettings().optimizeInList) {
return;
}
ExpressionColumn l = (ExpressionColumn) left;
if (filter != l.getTableFilter()) {
return;
if (left instanceof ExpressionColumn) {
ExpressionColumn l = (ExpressionColumn) left;
if (filter == l.getTableFilter()) {
createIndexConditions(filter, l, valueList);
}
} else if (left instanceof ExpressionList) {
ExpressionList list = (ExpressionList) left;
if (!list.isArray()) {
createIndexConditions(filter, list);
}
}
if (session.getDatabase().getSettings().optimizeInList) {
ExpressionVisitor visitor = ExpressionVisitor.getNotFromResolverVisitor(filter);
TypeInfo colType = l.getType();
for (Expression e : valueList) {
if (!e.isEverything(visitor)
|| !TypeInfo.haveSameOrdering(colType, TypeInfo.getHigherType(colType, e.getType()))) {
return;
}

private void createIndexConditions(TableFilter filter, ExpressionList list) {
int c = list.getSubexpressionCount();
for (int i = 0; i < c; i++) {
Expression e = list.getSubexpression(i);
if (e instanceof ExpressionColumn) {
ExpressionColumn l = (ExpressionColumn) e;
if (filter == l.getTableFilter()) {
ArrayList<Expression> subList = new ArrayList<>(valueList.size());
for (Expression row : valueList) {
if (row instanceof ExpressionList) {
ExpressionList r = (ExpressionList) row;
if (r.isArray() || r.getSubexpressionCount() != c) {
return;
}
subList.add(r.getSubexpression(i));
} else if (row instanceof ValueExpression) {
Value v = row.getValue(null);
if (v.getValueType() != Value.ROW) {
return;
}
Value[] values = ((ValueRow) v).getList();
if (c != values.length) {
return;
}
subList.add(ValueExpression.get(values[i]));
} else {
return;
}
}
createIndexConditions(filter, l, subList);
}
}
filter.addIndexCondition(IndexCondition.getInList(l, valueList));
}
}

private static void createIndexConditions(TableFilter filter, ExpressionColumn l, //
ArrayList<Expression> valueList) {
ExpressionVisitor visitor = ExpressionVisitor.getNotFromResolverVisitor(filter);
TypeInfo colType = l.getType();
for (Expression e : valueList) {
if (!e.isEverything(visitor)
|| !TypeInfo.haveSameOrdering(colType, TypeInfo.getHigherType(colType, e.getType()))) {
return;
}
}
filter.addIndexCondition(IndexCondition.getInList(l, valueList));
}

@Override
public void setEvaluatable(TableFilter tableFilter, boolean b) {
left.setEvaluatable(tableFilter, b);
Expand Down
Expand Up @@ -11,14 +11,17 @@
import org.h2.engine.SessionLocal;
import org.h2.expression.Expression;
import org.h2.expression.ExpressionColumn;
import org.h2.expression.ExpressionList;
import org.h2.expression.ExpressionVisitor;
import org.h2.expression.ValueExpression;
import org.h2.index.IndexCondition;
import org.h2.table.ColumnResolver;
import org.h2.table.TableFilter;
import org.h2.value.TypeInfo;
import org.h2.value.Value;
import org.h2.value.ValueBoolean;
import org.h2.value.ValueNull;
import org.h2.value.ValueRow;

/**
* Used for optimised IN(...) queries where the contents of the IN list are all
Expand Down Expand Up @@ -125,21 +128,69 @@ public Expression getNotIfPossible(SessionLocal session) {

@Override
public void createIndexConditions(SessionLocal session, TableFilter filter) {
if (not || whenOperand || !(left instanceof ExpressionColumn)) {
if (not || whenOperand || !session.getDatabase().getSettings().optimizeInList) {
return;
}
ExpressionColumn l = (ExpressionColumn) left;
if (filter != l.getTableFilter()) {
return;
if (left instanceof ExpressionColumn) {
ExpressionColumn l = (ExpressionColumn) left;
if (filter == l.getTableFilter()) {
createIndexConditions(filter, l, valueList, type);
}
} else if (left instanceof ExpressionList) {
ExpressionList list = (ExpressionList) left;
if (!list.isArray()) {
createIndexConditions(filter, list);
}
}
if (session.getDatabase().getSettings().optimizeInList) {
TypeInfo colType = l.getType();
if (TypeInfo.haveSameOrdering(colType, TypeInfo.getHigherType(colType, type))) {
filter.addIndexCondition(IndexCondition.getInList(l, valueList));
}

private void createIndexConditions(TableFilter filter, ExpressionList list) {
int c = list.getSubexpressionCount();
for (int i = 0; i < c; i++) {
Expression e = list.getSubexpression(i);
if (e instanceof ExpressionColumn) {
ExpressionColumn l = (ExpressionColumn) e;
if (filter == l.getTableFilter()) {
ArrayList<Expression> subList = new ArrayList<>(valueList.size());
for (Expression row : valueList) {
if (row instanceof ExpressionList) {
ExpressionList r = (ExpressionList) row;
if (r.isArray() || r.getSubexpressionCount() != c) {
return;
}
subList.add(r.getSubexpression(i));
} else if (row instanceof ValueExpression) {
Value v = row.getValue(null);
if (v.getValueType() != Value.ROW) {
return;
}
Value[] values = ((ValueRow) v).getList();
if (c != values.length) {
return;
}
subList.add(ValueExpression.get(values[i]));
} else {
return;
}
}
TypeInfo type = l.getType();
for (Expression expression : subList) {
type = TypeInfo.getHigherType(type, expression.getType());
}
createIndexConditions(filter, l, subList, type);
}
}
}
}

private static void createIndexConditions(TableFilter filter, ExpressionColumn l, ArrayList<Expression> valueList,
TypeInfo type) {
TypeInfo colType = l.getType();
if (TypeInfo.haveSameOrdering(colType, TypeInfo.getHigherType(colType, type))) {
filter.addIndexCondition(IndexCondition.getInList(l, valueList));
}
}

@Override
public void setEvaluatable(TableFilter tableFilter, boolean b) {
left.setEvaluatable(tableFilter, b);
Expand Down
6 changes: 2 additions & 4 deletions h2/src/main/org/h2/expression/condition/ConditionInQuery.java
Expand Up @@ -221,10 +221,8 @@ public int getCost() {

@Override
public void createIndexConditions(SessionLocal session, TableFilter filter) {
if (!session.getDatabase().getSettings().optimizeInList) {
return;
}
if (not || compareType != Comparison.EQUAL) {
if (not || whenOperand || compareType != Comparison.EQUAL
|| !session.getDatabase().getSettings().optimizeInList) {
return;
}
if (query.getColumnCount() != 1) {
Expand Down
Expand Up @@ -778,7 +778,7 @@ INSERT INTO TEST (SELECT X, X + 1, X + 2 FROM SYSTEM_RANGE(1, 5));
> update count: 5

EXPLAIN UPDATE TEST T SET V = V.V FROM (VALUES (1, 2, 4)) V(ID1, ID2, V) WHERE (T.ID1, T.ID2) = (V.ID1, V.ID2);
>> MERGE INTO "PUBLIC"."TEST" "T" /* PUBLIC.PRIMARY_KEY_2 */ USING (VALUES (1, 2, 4)) "V"("ID1", "ID2", "V") /* table scan */ ON (ROW ("T"."ID1", "T"."ID2") = ROW ("V"."ID1", "V"."ID2")) WHEN MATCHED THEN UPDATE SET "V" = "V"."V"
>> MERGE INTO "PUBLIC"."TEST" "T" /* PUBLIC.PRIMARY_KEY_2: ID1 = V.ID1 AND ID2 = V.ID2 */ USING (VALUES (1, 2, 4)) "V"("ID1", "ID2", "V") /* table scan */ ON (ROW ("T"."ID1", "T"."ID2") = ROW ("V"."ID1", "V"."ID2")) WHEN MATCHED THEN UPDATE SET "V" = "V"."V"

UPDATE TEST T SET V = V.V FROM (VALUES (1, 2, 4)) V(ID1, ID2, V) WHERE (T.ID1, T.ID2) = (V.ID1, V.ID2);
> update count: 1
Expand Down
8 changes: 4 additions & 4 deletions h2/src/test/org/h2/test/scripts/predicates/null.sql
Expand Up @@ -135,7 +135,7 @@ SELECT * FROM TEST T1 JOIN TEST T2 ON (T1.A, T1.B) = (T2.A, T2.B) WHERE (T2.A, T
> rows: 0

EXPLAIN SELECT * FROM TEST T1 JOIN TEST T2 ON (T1.A, T1.B) = (T2.A, T2.B) WHERE (T2.A, T2.B) IS NULL;
>> SELECT "T1"."A", "T1"."B", "T2"."A", "T2"."B" FROM "PUBLIC"."TEST" "T2" /* PUBLIC.TEST_A_B_IDX: A IS NULL AND B IS NULL */ /* WHERE ROW (T2.A, T2.B) IS NULL */ INNER JOIN "PUBLIC"."TEST" "T1" /* PUBLIC.TEST_A_B_IDX */ ON 1=1 WHERE (ROW ("T2"."A", "T2"."B") IS NULL) AND (ROW ("T1"."A", "T1"."B") = ROW ("T2"."A", "T2"."B"))
>> SELECT "T1"."A", "T1"."B", "T2"."A", "T2"."B" FROM "PUBLIC"."TEST" "T2" /* PUBLIC.TEST_A_B_IDX: A IS NULL AND B IS NULL */ /* WHERE ROW (T2.A, T2.B) IS NULL */ INNER JOIN "PUBLIC"."TEST" "T1" /* PUBLIC.TEST_A_B_IDX: A = T2.A AND B = T2.B */ ON 1=1 WHERE (ROW ("T2"."A", "T2"."B") IS NULL) AND (ROW ("T1"."A", "T1"."B") = ROW ("T2"."A", "T2"."B"))

SELECT * FROM TEST T1 LEFT JOIN TEST T2 ON (T1.A, T1.B) = (T2.A, T2.B) WHERE (T2.A, T2.B) IS NULL;
> A B A B
Expand All @@ -146,7 +146,7 @@ SELECT * FROM TEST T1 LEFT JOIN TEST T2 ON (T1.A, T1.B) = (T2.A, T2.B) WHERE (T2
> rows: 3

EXPLAIN SELECT * FROM TEST T1 LEFT JOIN TEST T2 ON (T1.A, T1.B) = (T2.A, T2.B) WHERE (T2.A, T2.B) IS NULL;
>> SELECT "T1"."A", "T1"."B", "T2"."A", "T2"."B" FROM "PUBLIC"."TEST" "T1" /* PUBLIC.TEST_A_B_IDX */ LEFT OUTER JOIN "PUBLIC"."TEST" "T2" /* PUBLIC.TEST_A_B_IDX */ ON ROW ("T1"."A", "T1"."B") = ROW ("T2"."A", "T2"."B") WHERE ROW ("T2"."A", "T2"."B") IS NULL
>> SELECT "T1"."A", "T1"."B", "T2"."A", "T2"."B" FROM "PUBLIC"."TEST" "T1" /* PUBLIC.TEST_A_B_IDX */ LEFT OUTER JOIN "PUBLIC"."TEST" "T2" /* PUBLIC.TEST_A_B_IDX: A = T1.A AND B = T1.B */ ON ROW ("T1"."A", "T1"."B") = ROW ("T2"."A", "T2"."B") WHERE ROW ("T2"."A", "T2"."B") IS NULL

SELECT * FROM TEST T1 JOIN TEST T2 ON (T1.A, T1.B) = (T2.A, T2.B) WHERE (T2.A, T2.B) IS NOT NULL;
> A B A B
Expand All @@ -155,7 +155,7 @@ SELECT * FROM TEST T1 JOIN TEST T2 ON (T1.A, T1.B) = (T2.A, T2.B) WHERE (T2.A, T
> rows: 1

EXPLAIN SELECT * FROM TEST T1 JOIN TEST T2 ON (T1.A, T1.B) = (T2.A, T2.B) WHERE (T2.A, T2.B) IS NOT NULL;
>> SELECT "T1"."A", "T1"."B", "T2"."A", "T2"."B" FROM "PUBLIC"."TEST" "T1" /* PUBLIC.TEST_A_B_IDX */ INNER JOIN "PUBLIC"."TEST" "T2" /* PUBLIC.TEST_A_B_IDX */ ON 1=1 WHERE (ROW ("T2"."A", "T2"."B") IS NOT NULL) AND (ROW ("T1"."A", "T1"."B") = ROW ("T2"."A", "T2"."B"))
>> SELECT "T1"."A", "T1"."B", "T2"."A", "T2"."B" FROM "PUBLIC"."TEST" "T1" /* PUBLIC.TEST_A_B_IDX */ INNER JOIN "PUBLIC"."TEST" "T2" /* PUBLIC.TEST_A_B_IDX: A = T1.A AND B = T1.B */ ON 1=1 WHERE (ROW ("T2"."A", "T2"."B") IS NOT NULL) AND (ROW ("T1"."A", "T1"."B") = ROW ("T2"."A", "T2"."B"))

SELECT * FROM TEST T1 LEFT JOIN TEST T2 ON (T1.A, T1.B) = (T2.A, T2.B) WHERE (T2.A, T2.B) IS NOT NULL;
> A B A B
Expand All @@ -164,7 +164,7 @@ SELECT * FROM TEST T1 LEFT JOIN TEST T2 ON (T1.A, T1.B) = (T2.A, T2.B) WHERE (T2
> rows: 1

EXPLAIN SELECT * FROM TEST T1 LEFT JOIN TEST T2 ON (T1.A, T1.B) = (T2.A, T2.B) WHERE (T2.A, T2.B) IS NOT NULL;
>> SELECT "T1"."A", "T1"."B", "T2"."A", "T2"."B" FROM "PUBLIC"."TEST" "T1" /* PUBLIC.TEST_A_B_IDX */ LEFT OUTER JOIN "PUBLIC"."TEST" "T2" /* PUBLIC.TEST_A_B_IDX */ ON ROW ("T1"."A", "T1"."B") = ROW ("T2"."A", "T2"."B") WHERE ROW ("T2"."A", "T2"."B") IS NOT NULL
>> SELECT "T1"."A", "T1"."B", "T2"."A", "T2"."B" FROM "PUBLIC"."TEST" "T1" /* PUBLIC.TEST_A_B_IDX */ LEFT OUTER JOIN "PUBLIC"."TEST" "T2" /* PUBLIC.TEST_A_B_IDX: A = T1.A AND B = T1.B */ ON ROW ("T1"."A", "T1"."B") = ROW ("T2"."A", "T2"."B") WHERE ROW ("T2"."A", "T2"."B") IS NOT NULL

EXPLAIN SELECT A, B FROM TEST WHERE (A, NULL) IS NULL;
>> SELECT "A", "B" FROM "PUBLIC"."TEST" /* PUBLIC.TEST_A_B_IDX: A IS NULL */ WHERE "A" IS NULL
Expand Down

0 comments on commit 55797e5

Please sign in to comment.