提交 21d6421e authored 作者: Thomas Mueller's avatar Thomas Mueller

The condition "in(select ...)" did not work correctly if the subquery could not…

The condition "in(select ...)" did not work correctly if the subquery could not be converted to a "distinct" query, as in: "select * from dual where x in (select x from dual group by x order by max(x))".
上级 fe9c54b0
......@@ -22,6 +22,7 @@ Change Log
</li><li>The condition "in(select ...)" did not work correctly if the subquery
could not be converted to a "distinct" query, as in:
"select * from dual where x in (select x from dual group by x order by max(x))".
Now the subquery needs to be made distinct manually if this optimization is needed.
</li><li>In the last release, the error code for "Wrong user name or password" was still
08004 instead of 28000, which resulted in the wrong error message.
</li><li>In some cases, creating a new table or altering an existing table threw the exception:
......
......@@ -118,7 +118,6 @@ public class ConditionInSelect extends Condition {
public Expression optimize(Session session) {
left = left.optimize(session);
query.setDistinct(true);
query.setRandomAccessResult(true);
query.prepare();
if (query.getColumnCount() != 1) {
......
......@@ -186,14 +186,23 @@ public class LocalResult implements ResultInterface, ResultTarget {
* @return true if the row exists
*/
public boolean containsDistinct(Value[] values) {
if (!distinct) {
DbException.throwInternalError();
if (external != null) {
return external.contains(values);
}
if (distinctRows != null) {
ValueArray array = ValueArray.get(values);
return distinctRows.get(array) != null;
if (distinctRows == null) {
distinctRows = ValueHashMap.newInstance();
for (Value[] row : rows) {
if (row.length > visibleColumnCount) {
Value[] r2 = new Value[visibleColumnCount];
System.arraycopy(row, 0, r2, 0, visibleColumnCount);
row = r2;
}
ValueArray array = ValueArray.get(row);
distinctRows.put(array, row);
}
}
return external.contains(values);
ValueArray array = ValueArray.get(values);
return distinctRows.get(array) != null;
}
public void reset() {
......
--- special grammar and test cases ---------------------------------------------------------------------------------------------
select * from dual where x in (select x from dual group by x order by max(x));
> X
> -
> 1
> rows (ordered): 1
create table test(d decimal(1, 2));
> exception
......@@ -1028,8 +1034,8 @@ insert into t2 select x from system_range(1, 1000);
explain select count(*) from t1 where t1.id in ( select t2.id from t2 );
> PLAN
> ------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
> SELECT COUNT(*) FROM PUBLIC.T1 /* PUBLIC.PRIMARY_KEY_A: ID IN(SELECT DISTINCT T2.ID FROM PUBLIC.T2 /++ PUBLIC.T2.tableScan ++/) */ WHERE T1.ID IN( SELECT DISTINCT T2.ID FROM PUBLIC.T2 /* PUBLIC.T2.tableScan */)
> ------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
> SELECT COUNT(*) FROM PUBLIC.T1 /* PUBLIC.PRIMARY_KEY_A: ID IN(SELECT T2.ID FROM PUBLIC.T2 /++ PUBLIC.T2.tableScan ++/) */ WHERE T1.ID IN( SELECT T2.ID FROM PUBLIC.T2 /* PUBLIC.T2.tableScan */)
> rows: 1
select count(*) from t1 where t1.id in ( select t2.id from t2 );
......@@ -3155,8 +3161,8 @@ where exists (select 1 from test t4 where t2.id=t4.id);
explain select * from test t1 where id in(select id from test t2 where t1.id=t2.id);
> PLAN
> -------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
> SELECT T1.ID, T1.NAME FROM PUBLIC.TEST T1 /* PUBLIC.TEST.tableScan */ WHERE ID IN( SELECT DISTINCT ID FROM PUBLIC.TEST T2 /* PUBLIC.PRIMARY_KEY_2: ID = T1.ID */ WHERE T1.ID = T2.ID)
> ----------------------------------------------------------------------------------------------------------------------------------------------------------------------------
> SELECT T1.ID, T1.NAME FROM PUBLIC.TEST T1 /* PUBLIC.TEST.tableScan */ WHERE ID IN( SELECT ID FROM PUBLIC.TEST T2 /* PUBLIC.PRIMARY_KEY_2: ID = T1.ID */ WHERE T1.ID = T2.ID)
> rows: 1
select * from test t1 where id in(select id from test t2 where t1.id=t2.id);
......@@ -3194,8 +3200,8 @@ select * from test t1 where id in(id);
explain select * from test t1 where id in(select id from test);
> PLAN
> ----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
> SELECT T1.ID, T1.NAME FROM PUBLIC.TEST T1 /* PUBLIC.PRIMARY_KEY_2: ID IN(SELECT DISTINCT ID FROM PUBLIC.TEST /++ PUBLIC.TEST.tableScan ++/) */ WHERE ID IN( SELECT DISTINCT ID FROM PUBLIC.TEST /* PUBLIC.TEST.tableScan */)
> ----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
> SELECT T1.ID, T1.NAME FROM PUBLIC.TEST T1 /* PUBLIC.PRIMARY_KEY_2: ID IN(SELECT ID FROM PUBLIC.TEST /++ PUBLIC.TEST.tableScan ++/) */ WHERE ID IN( SELECT ID FROM PUBLIC.TEST /* PUBLIC.TEST.tableScan */)
> rows: 1
select * from test t1 where id in(select id from test);
......@@ -6116,14 +6122,14 @@ EXPLAIN PLAN FOR SELECT * FROM TEST T1 WHERE ID IN(1, 2);
EXPLAIN PLAN FOR SELECT * FROM TEST T1 WHERE ID IN(SELECT ID FROM TEST);
> PLAN
> ----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
> SELECT T1.ID, T1.NAME FROM PUBLIC.TEST T1 /* PUBLIC.PRIMARY_KEY_2: ID IN(SELECT DISTINCT ID FROM PUBLIC.TEST /++ PUBLIC.TEST.tableScan ++/) */ WHERE ID IN( SELECT DISTINCT ID FROM PUBLIC.TEST /* PUBLIC.TEST.tableScan */)
> ----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
> SELECT T1.ID, T1.NAME FROM PUBLIC.TEST T1 /* PUBLIC.PRIMARY_KEY_2: ID IN(SELECT ID FROM PUBLIC.TEST /++ PUBLIC.TEST.tableScan ++/) */ WHERE ID IN( SELECT ID FROM PUBLIC.TEST /* PUBLIC.TEST.tableScan */)
> rows: 1
EXPLAIN PLAN FOR SELECT * FROM TEST T1 WHERE ID NOT IN(SELECT ID FROM TEST);
> PLAN
> ---------------------------------------------------------------------------------------------------------------------------------------------------------
> SELECT T1.ID, T1.NAME FROM PUBLIC.TEST T1 /* PUBLIC.TEST.tableScan */ WHERE NOT (ID IN( SELECT DISTINCT ID FROM PUBLIC.TEST /* PUBLIC.TEST.tableScan */))
> ------------------------------------------------------------------------------------------------------------------------------------------------
> SELECT T1.ID, T1.NAME FROM PUBLIC.TEST T1 /* PUBLIC.TEST.tableScan */ WHERE NOT (ID IN( SELECT ID FROM PUBLIC.TEST /* PUBLIC.TEST.tableScan */))
> rows: 1
EXPLAIN PLAN FOR SELECT CAST(ID AS VARCHAR(255)) FROM TEST;
......
Markdown 格式
0%
您添加了 0 到此讨论。请谨慎行事。
请先完成此评论的编辑!
注册 或者 后发表评论