提交 96f1642d authored 作者: Thomas Mueller's avatar Thomas Mueller

Comparison of integer columns against float numbers was not always correct. Issue 182.

上级 9583bf13
......@@ -7,7 +7,6 @@
package org.h2.expression;
import java.util.Arrays;
import org.h2.constant.ErrorCode;
import org.h2.constant.SysProperties;
import org.h2.engine.Database;
import org.h2.engine.Session;
......@@ -86,7 +85,6 @@ public class Comparison extends Condition {
private int compareType;
private Expression left;
private Expression right;
private int dataType = -2;
public Comparison(Session session, int compareType, Expression left, Expression right) {
this.database = session.getDatabase();
......@@ -128,25 +126,10 @@ public class Comparison extends Condition {
return "(" + sql + ")";
}
private Expression getCast(Expression expr, int targetDataType, long precision, int scale, int displaySize, Session session)
{
if (expr == ValueExpression.getNull()) {
return expr;
}
Function function = Function.getFunction(session.getDatabase(), "CAST");
function.setParameter(0, expr);
function.setDataType(targetDataType, precision, scale, displaySize);
function.doneWithParameters();
return function.optimize(session);
}
public Expression optimize(Session session) {
left = left.optimize(session);
if (right == null) {
dataType = left.getType();
} else {
if (right != null) {
right = right.optimize(session);
try {
if (right instanceof ExpressionColumn) {
if (left.isConstant() || left instanceof Parameter) {
Expression temp = left;
......@@ -161,40 +144,9 @@ public class Comparison extends Condition {
if (r == ValueNull.INSTANCE) {
return ValueExpression.getNull();
}
Expression test = getCast(right, left.getType(), left.getPrecision(), left.getScale(), left.getDisplaySize(), session);
if (!database.areEqual(r, test.getValue(session))) {
return ValueExpression.get(ValueBoolean.get(false));
}
right = test;
} else if (right instanceof Parameter) {
((Parameter) right).setColumn(((ExpressionColumn) left).getColumn());
}
}
} catch (DbException e) {
if (e.getErrorCode() == ErrorCode.NUMERIC_VALUE_OUT_OF_RANGE) {
// WHERE ID=100000000000
return ValueExpression.get(ValueBoolean.get(false));
}
throw e;
}
int lt = left.getType(), rt = right.getType();
if (lt == rt) {
if (lt == Value.UNKNOWN) {
throw DbException.get(ErrorCode.UNKNOWN_DATA_TYPE_1, getSQL());
}
dataType = lt;
} else {
dataType = Value.getHigherOrder(left.getType(), right.getType());
long precision = Math.max(left.getPrecision(), right.getPrecision());
int scale = Math.max(left.getScale(), right.getScale());
int displaySize = Math.max(left.getDisplaySize(), right.getDisplaySize());
if (dataType != lt) {
left = getCast(left, dataType, precision, scale, displaySize, session);
}
if (dataType != rt) {
right = getCast(right, dataType, precision, scale, displaySize, session);
}
}
}
if (compareType == IS_NULL || compareType == IS_NOT_NULL) {
......@@ -240,6 +192,7 @@ public class Comparison extends Condition {
if (r == ValueNull.INSTANCE) {
return ValueNull.INSTANCE;
}
int dataType = Value.getHigherOrder(left.getType(), right.getType());
l = l.convertTo(dataType);
r = r.convertTo(dataType);
boolean result = compareNotNull(database, l, r, compareType);
......
......@@ -87,7 +87,7 @@ public class IndexCursor implements Cursor {
inResult = condition.getCurrentResult(s);
}
} else {
Value v = column.convert(condition.getCurrentValue(s));
Value v = condition.getCurrentValue(s);
boolean isStart = condition.isStart();
boolean isEnd = condition.isEnd();
int id = column.getColumnId();
......
......@@ -39,10 +39,18 @@ public class RangeIndex extends BaseIndex {
}
public Cursor find(Session session, SearchRow first, SearchRow last) {
long min = rangeTable.getMin(session);
long max = rangeTable.getMax(session);
long start = Math.max(min, first == null ? min : first.getValue(0).getLong());
long end = Math.min(max, last == null ? max : last.getValue(0).getLong());
long min = rangeTable.getMin(session), start = min;
long max = rangeTable.getMax(session), end = max;
try {
start = Math.max(min, first == null ? min : first.getValue(0).getLong());
} catch (Exception e) {
// error when converting the value - ignore
}
try {
end = Math.min(max, last == null ? max : last.getValue(0).getLong());
} catch (Exception e) {
// error when converting the value - ignore
}
return new RangeCursor(start, end);
}
......
......@@ -920,8 +920,8 @@ public abstract class Table extends SchemaObjectBase {
}
/**
* Compare two values with the current comparison mode. The values must be
* of the same type.
* Compare two values with the current comparison mode. The values may be of
* different type.
*
* @param a the first value
* @param b the second value
......@@ -929,6 +929,9 @@ public abstract class Table extends SchemaObjectBase {
* 1 otherwise
*/
public int compareTypeSave(Value a, Value b) {
int dataType = Value.getHigherOrder(a.getType(), b.getType());
a = a.convertTo(dataType);
b = b.convertTo(dataType);
return a.compareTypeSave(b, compareMode);
}
......
......@@ -35,6 +35,7 @@ public class TestCases extends TestBase {
}
public void test() throws Exception {
testCompareDoubleWithIntColumn();
testDeleteIndexOutOfBounds();
testOrderByWithSubselect();
testInsertDeleteRollback();
......@@ -77,6 +78,40 @@ public class TestCases extends TestBase {
deleteDb("cases");
}
private void testCompareDoubleWithIntColumn() throws SQLException {
deleteDb("cases");
Connection conn = getConnection("cases");
Statement stat = conn.createStatement();
testCompareDoubleWithIntColumn(stat, false, 0.1, false);
testCompareDoubleWithIntColumn(stat, false, 0.1, true);
testCompareDoubleWithIntColumn(stat, false, 0.9, false);
testCompareDoubleWithIntColumn(stat, false, 0.9, true);
testCompareDoubleWithIntColumn(stat, true, 0.1, false);
testCompareDoubleWithIntColumn(stat, true, 0.1, true);
testCompareDoubleWithIntColumn(stat, true, 0.9, false);
testCompareDoubleWithIntColumn(stat, true, 0.9, true);
conn.close();
}
private void testCompareDoubleWithIntColumn(Statement stat, boolean pk, double x, boolean prepared) throws SQLException {
if (pk) {
stat.execute("create table test(id int primary key)");
} else {
stat.execute("create table test(id int)");
}
stat.execute("insert into test values(1)");
ResultSet rs;
if (prepared) {
PreparedStatement prep = stat.getConnection().prepareStatement("select * from test where id > ?");
prep.setDouble(1, x);
rs = prep.executeQuery();
} else {
rs = stat.executeQuery("select * from test where id > " + x);
}
assertTrue(rs.next());
stat.execute("drop table test");
}
private void testDeleteIndexOutOfBounds() throws SQLException {
if (config.memory || !config.big) {
return;
......
......@@ -1008,8 +1008,8 @@ explain select * from (select dir_num, count(*) as cnt from multi_pages t, b_ho
where t.bh_id=bh.id and bh.site='Hello' group by dir_num) as x
where cnt < 1000 order by dir_num asc;
> PLAN
> ------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
> SELECT X.DIR_NUM, X.CNT FROM (SELECT DIR_NUM, COUNT(*) AS CNT FROM PUBLIC.MULTI_PAGES T /* PUBLIC.MULTI_PAGES.tableScan */ INNER JOIN PUBLIC.B_HOLDING BH /* PUBLIC.PRIMARY_KEY_3: ID = T.BH_ID */ ON 1=1 WHERE (BH.SITE = 'Hello') AND (T.BH_ID = BH.ID) GROUP BY DIR_NUM) X /* SELECT DIR_NUM, COUNT(*) AS CNT FROM PUBLIC.MULTI_PAGES T /++ PUBLIC.MULTI_PAGES.tableScan ++/ INNER JOIN PUBLIC.B_HOLDING BH /++ PUBLIC.PRIMARY_KEY_3: ID = T.BH_ID ++/ ON 1=1 WHERE (BH.SITE = 'Hello') AND (T.BH_ID = BH.ID) GROUP BY DIR_NUM HAVING COUNT(*) <= CAST(?1 AS BIGINT): CNT < 1000 */ WHERE CNT < 1000 ORDER BY 1
> --------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
> SELECT X.DIR_NUM, X.CNT FROM (SELECT DIR_NUM, COUNT(*) AS CNT FROM PUBLIC.MULTI_PAGES T /* PUBLIC.MULTI_PAGES.tableScan */ INNER JOIN PUBLIC.B_HOLDING BH /* PUBLIC.PRIMARY_KEY_3: ID = T.BH_ID */ ON 1=1 WHERE (BH.SITE = 'Hello') AND (T.BH_ID = BH.ID) GROUP BY DIR_NUM) X /* SELECT DIR_NUM, COUNT(*) AS CNT FROM PUBLIC.MULTI_PAGES T /++ PUBLIC.MULTI_PAGES.tableScan ++/ INNER JOIN PUBLIC.B_HOLDING BH /++ PUBLIC.PRIMARY_KEY_3: ID = T.BH_ID ++/ ON 1=1 WHERE (BH.SITE = 'Hello') AND (T.BH_ID = BH.ID) GROUP BY DIR_NUM HAVING COUNT(*) <= ?1: CNT < 1000 */ WHERE CNT < 1000 ORDER BY 1
> rows (ordered): 1
select dir_num, count(*) as cnt from multi_pages t, b_holding bh
......@@ -1083,8 +1083,8 @@ explain select * from test where id = 3;
explain select * from test where id = 255;
> PLAN
> ------------------------------------------------------------------------------
> SELECT TEST.ID FROM PUBLIC.TEST /* PUBLIC.TEST.tableScan: FALSE */ WHERE FALSE
> -----------------------------------------------------------------------------------
> SELECT TEST.ID FROM PUBLIC.TEST /* PUBLIC.PRIMARY_KEY_2: ID = 255 */ WHERE ID = 255
> rows: 1
drop table test;
......@@ -1404,8 +1404,8 @@ select * from test where name = -1 and name = id;
explain select * from test where name = -1 and name = id;
> PLAN
> ---------------------------------------------------------------------------------------------------------------------------
> SELECT TEST.ID, TEST.NAME FROM PUBLIC.TEST /* PUBLIC.TEST.tableScan */ WHERE (NAME = '-1') AND (CAST(NAME AS INTEGER) = ID)
> --------------------------------------------------------------------------------------------------------------------------------
> SELECT TEST.ID, TEST.NAME FROM PUBLIC.TEST /* PUBLIC.PRIMARY_KEY_2: ID = -1 */ WHERE ((NAME = -1) AND (NAME = ID)) AND (ID = -1)
> rows: 1
DROP TABLE TEST;
......@@ -2647,8 +2647,8 @@ select * from test2 where name like 'HELLO';
explain plan for select * from test2, test where test2.name = test.name;
> PLAN
> ----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
> SELECT TEST2.ID, TEST2.NAME, TEST.ID, TEST.NAME FROM PUBLIC.TEST2 /* PUBLIC.TEST2.tableScan */ INNER JOIN PUBLIC.TEST /* PUBLIC.TEST.tableScan */ ON 1=1 WHERE TEST2.NAME = CAST(TEST.NAME AS VARCHAR_IGNORECASE(255))
> -------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
> SELECT TEST2.ID, TEST2.NAME, TEST.ID, TEST.NAME FROM PUBLIC.TEST2 /* PUBLIC.TEST2.tableScan */ INNER JOIN PUBLIC.TEST /* PUBLIC.IDX_TEST_NAME: NAME = TEST2.NAME */ ON 1=1 WHERE TEST2.NAME = TEST.NAME
> rows: 1
select * from test2, test where test2.name = test.name;
......@@ -2660,8 +2660,8 @@ select * from test2, test where test2.name = test.name;
explain plan for select * from test, test2 where test2.name = test.name;
> PLAN
> ----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
> SELECT TEST.ID, TEST.NAME, TEST2.ID, TEST2.NAME FROM PUBLIC.TEST2 /* PUBLIC.TEST2.tableScan */ INNER JOIN PUBLIC.TEST /* PUBLIC.TEST.tableScan */ ON 1=1 WHERE TEST2.NAME = CAST(TEST.NAME AS VARCHAR_IGNORECASE(255))
> -------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
> SELECT TEST.ID, TEST.NAME, TEST2.ID, TEST2.NAME FROM PUBLIC.TEST2 /* PUBLIC.TEST2.tableScan */ INNER JOIN PUBLIC.TEST /* PUBLIC.IDX_TEST_NAME: NAME = TEST2.NAME */ ON 1=1 WHERE TEST2.NAME = TEST.NAME
> rows: 1
select * from test, test2 where test2.name = test.name;
......@@ -2676,8 +2676,8 @@ create index idx_test2_name on test2(name);
explain plan for select * from test2, test where test2.name = test.name;
> PLAN
> ------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
> SELECT TEST2.ID, TEST2.NAME, TEST.ID, TEST.NAME FROM PUBLIC.TEST /* PUBLIC.TEST.tableScan */ INNER JOIN PUBLIC.TEST2 /* PUBLIC.IDX_TEST2_NAME: NAME = CAST(TEST.NAME AS VARCHAR_IGNORECASE(255)) */ ON 1=1 WHERE TEST2.NAME = CAST(TEST.NAME AS VARCHAR_IGNORECASE(255))
> -------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
> SELECT TEST2.ID, TEST2.NAME, TEST.ID, TEST.NAME FROM PUBLIC.TEST2 /* PUBLIC.TEST2.tableScan */ INNER JOIN PUBLIC.TEST /* PUBLIC.IDX_TEST_NAME: NAME = TEST2.NAME */ ON 1=1 WHERE TEST2.NAME = TEST.NAME
> rows: 1
select * from test2, test where test2.name = test.name;
......@@ -2689,8 +2689,8 @@ select * from test2, test where test2.name = test.name;
explain plan for select * from test, test2 where test2.name = test.name;
> PLAN
> ------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
> SELECT TEST.ID, TEST.NAME, TEST2.ID, TEST2.NAME FROM PUBLIC.TEST /* PUBLIC.TEST.tableScan */ INNER JOIN PUBLIC.TEST2 /* PUBLIC.IDX_TEST2_NAME: NAME = CAST(TEST.NAME AS VARCHAR_IGNORECASE(255)) */ ON 1=1 WHERE TEST2.NAME = CAST(TEST.NAME AS VARCHAR_IGNORECASE(255))
> ------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
> SELECT TEST.ID, TEST.NAME, TEST2.ID, TEST2.NAME FROM PUBLIC.TEST /* PUBLIC.TEST.tableScan */ INNER JOIN PUBLIC.TEST2 /* PUBLIC.IDX_TEST2_NAME: NAME = TEST.NAME */ ON 1=1 WHERE TEST2.NAME = TEST.NAME
> rows: 1
select * from test, test2 where test2.name = test.name;
......@@ -7324,8 +7324,8 @@ select * from s;
> rows: 1
select some(y>10), every(y>10), min(y), max(y) from t;
> BOOL_OR(Y > 10.0) BOOL_AND(Y > 10.0) MIN(Y) MAX(Y)
> ----------------- ------------------ ------ ------
> BOOL_OR(Y > 10) BOOL_AND(Y > 10) MIN(Y) MAX(Y)
> --------------- ---------------- ------ ------
> null null null null
> rows: 1
......@@ -7382,8 +7382,8 @@ stddev_pop(distinct y) s_py, stddev_samp(distinct y) s_sy, var_pop(distinct y) v
> rows: 1
select some(y>10), every(y>10), min(y), max(y) from t;
> BOOL_OR(Y > 10.0) BOOL_AND(Y > 10.0) MIN(Y) MAX(Y)
> ----------------- ------------------ ------ ------
> BOOL_OR(Y > 10) BOOL_AND(Y > 10) MIN(Y) MAX(Y)
> --------------- ---------------- ------ ------
> TRUE FALSE 4.0 16.0
> rows: 1
......
Markdown 格式
0%
您添加了 0 到此讨论。请谨慎行事。
请先完成此评论的编辑!
注册 或者 后发表评论