Skip to content
项目
群组
代码片段
帮助
正在加载...
帮助
为 GitLab 提交贡献
登录/注册
切换导航
H
h2database
项目
项目
详情
活动
周期分析
仓库
仓库
文件
提交
分支
标签
贡献者
分枝图
比较
统计图
议题
0
议题
0
列表
看板
标记
里程碑
合并请求
0
合并请求
0
CI / CD
CI / CD
流水线
作业
计划
统计图
Wiki
Wiki
代码片段
代码片段
成员
成员
折叠边栏
关闭边栏
活动
分枝图
统计图
创建新议题
作业
提交
议题看板
打开侧边栏
Administrator
h2database
Commits
99bb7a1b
提交
99bb7a1b
authored
15 年前
作者:
Thomas Mueller
浏览文件
操作
浏览文件
下载
电子邮件补丁
差异文件
Statements with IN(SELECT..) conditions could produce the wrong result.
上级
82e4de37
隐藏空白字符变更
内嵌
并排
正在显示
3 个修改的文件
包含
35 行增加
和
10 行删除
+35
-10
changelog.html
h2/src/docsrc/html/changelog.html
+2
-0
IndexCursor.java
h2/src/main/org/h2/index/IndexCursor.java
+16
-10
TestOptimizations.java
h2/src/test/org/h2/test/db/TestOptimizations.java
+17
-0
没有找到文件。
h2/src/docsrc/html/changelog.html
浏览文件 @
99bb7a1b
...
...
@@ -25,6 +25,8 @@ Change Log
</li><li>
Optimization index conditions of the form 'column=NULL' (which is always false; unlike 'column IS NULL').
</li><li>
Script command and tool: the primary key constraint is now listed before inserting the data.
This will result in a smaller database when using the page store.
</li><li>
Statements with IN(SELECT..) conditions could produce the wrong result.
Example: index on id, name; query: select * from test where id between 1 and 3 and name in (select 'World').
</li><li>
Statements with IN(..) conditions could produce the wrong result when using views or nested select statements.
Example: index on id; index on name; query: select * from (select * from test) where id=1 and name in('a', 'b').
select * from (select * from test) where id=1 and name in('Hello', 'World').
...
...
This diff is collapsed.
Click to expand it.
h2/src/main/org/h2/index/IndexCursor.java
浏览文件 @
99bb7a1b
...
...
@@ -77,12 +77,16 @@ public class IndexCursor implements Cursor {
}
Column
column
=
condition
.
getColumn
();
if
(
condition
.
getCompareType
()
==
Comparison
.
IN_LIST
)
{
this
.
inColumn
=
column
;
inList
=
condition
.
getCurrentValueList
(
session
);
inListIndex
=
0
;
if
(
start
==
null
&&
end
==
null
)
{
this
.
inColumn
=
column
;
inList
=
condition
.
getCurrentValueList
(
session
);
inListIndex
=
0
;
}
}
else
if
(
condition
.
getCompareType
()
==
Comparison
.
IN_QUERY
)
{
this
.
inColumn
=
column
;
inResult
=
condition
.
getCurrentResult
(
session
);
if
(
start
==
null
&&
end
==
null
)
{
this
.
inColumn
=
column
;
inResult
=
condition
.
getCurrentResult
(
session
);
}
}
else
{
Value
v
=
column
.
convert
(
condition
.
getCurrentValue
(
session
));
boolean
isStart
=
condition
.
isStart
();
...
...
@@ -102,17 +106,19 @@ public class IndexCursor implements Cursor {
if
(
isEnd
)
{
end
=
getSearchRow
(
end
,
id
,
v
,
false
);
}
if
(
isStart
&&
isEnd
)
{
if
(
v
==
ValueNull
.
INSTANCE
)
{
// join on a column=NULL is always false
alwaysFalse
=
true
;
}
if
(
isStart
||
isEnd
)
{
// an X=? condition will produce less rows than
// an X IN(..) condition
inColumn
=
null
;
inList
=
null
;
inResult
=
null
;
}
if
(
isStart
&&
isEnd
)
{
if
(
v
==
ValueNull
.
INSTANCE
)
{
// join on a column=NULL is always false
alwaysFalse
=
true
;
}
}
}
}
if
(
inColumn
!=
null
)
{
...
...
This diff is collapsed.
Click to expand it.
h2/src/test/org/h2/test/db/TestOptimizations.java
浏览文件 @
99bb7a1b
...
...
@@ -38,6 +38,7 @@ public class TestOptimizations extends TestBase {
}
public
void
test
()
throws
Exception
{
testInAndBetween
();
testNestedIn
();
testNestedInSelectAndLike
();
testNestedInSelect
();
...
...
@@ -60,6 +61,22 @@ public class TestOptimizations extends TestBase {
deleteDb
(
"optimizations"
);
}
private
void
testInAndBetween
()
throws
SQLException
{
deleteDb
(
"optimizations"
);
Connection
conn
=
getConnection
(
"optimizations"
);
Statement
stat
=
conn
.
createStatement
();
ResultSet
rs
;
stat
.
execute
(
"create table test(id int, name varchar)"
);
stat
.
execute
(
"create index idx_name on test(id, name)"
);
stat
.
execute
(
"insert into test values(1, 'Hello'), (2, 'World')"
);
rs
=
stat
.
executeQuery
(
"select * from test where id between 1 and 3 and name in ('World')"
);
assertTrue
(
rs
.
next
());
rs
=
stat
.
executeQuery
(
"select * from test where id between 1 and 3 and name in (select 'World')"
);
assertTrue
(
rs
.
next
());
stat
.
execute
(
"drop table test"
);
conn
.
close
();
}
private
void
testNestedIn
()
throws
SQLException
{
deleteDb
(
"optimizations"
);
Connection
conn
=
getConnection
(
"optimizations"
);
...
...
This diff is collapsed.
Click to expand it.
编写
预览
Markdown
格式
0%
重试
或
添加新文件
添加附件
取消
您添加了
0
人
到此讨论。请谨慎行事。
请先完成此评论的编辑!
取消
请
注册
或者
登录
后发表评论