提交 10b2bc05 authored 作者: Thomas Mueller's avatar Thomas Mueller

The index condition columnName IS NULL was not efficient when using a clustered index.

上级 1f472b54
......@@ -74,7 +74,7 @@ class PageDataCursor implements Cursor {
private boolean checkMax() {
if (row != null) {
if (maxKey != Long.MAX_VALUE) {
long x = current.index.getKey(row, Long.MAX_VALUE);
long x = current.index.getKey(row, Long.MAX_VALUE, Long.MAX_VALUE);
if (x > maxKey) {
row = null;
return false;
......
......@@ -245,15 +245,18 @@ public class PageDataIndex extends PageIndex {
*
* @param row the row
* @param ifEmpty the value to use if the row is empty
* @param ifNull the value to use if the column is NULL
* @return the key
*/
long getKey(SearchRow row, long ifEmpty) {
long getKey(SearchRow row, long ifEmpty, long ifNull) {
if (row == null) {
return ifEmpty;
}
Value v = row.getValue(mainIndexColumn);
if (v == null || v == ValueNull.INSTANCE) {
return ifEmpty;
if (v == null) {
throw DbException.throwInternalError(row.toString());
} else if (v == ValueNull.INSTANCE) {
return ifNull;
}
return v.getLong();
}
......
......@@ -53,8 +53,10 @@ public class PageDelegateIndex extends PageIndex {
}
public Cursor find(Session session, SearchRow first, SearchRow last) {
long min = mainIndex.getKey(first, Long.MIN_VALUE);
long max = mainIndex.getKey(last, Long.MAX_VALUE);
long min = mainIndex.getKey(first, Long.MIN_VALUE, Long.MIN_VALUE);
// ifNull is MIN_VALUE as well, because the column is never NULL
// so avoid returning all rows (returning one row is OK)
long max = mainIndex.getKey(last, Long.MAX_VALUE, Long.MIN_VALUE);
return mainIndex.find(session, min, max, false);
}
......
--- special grammar and test cases ---------------------------------------------------------------------------------------------
create table test(id int primary key);
> ok
insert into test values(1), (2), (3), (4);
> update count: 4
explain analyze select * from test where id is null;
> PLAN
> ----------------------------------------------------------------------------------------------------------
> SELECT TEST.ID FROM PUBLIC.TEST /* PUBLIC.PRIMARY_KEY_2: ID IS NULL */ /* scanCount: 1 */ WHERE ID IS NULL
> rows: 1
drop table test;
> ok
explain analyze select 1;
> PLAN
> ----------------------------------------------------------------------------
......@@ -3121,8 +3136,8 @@ inner join test2 on test1.id=test2.id left
outer join test3 on test2.id=test3.id
where test3.id is null;
> PLAN
> --------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
> SELECT TEST1.ID, TEST2.ID, TEST3.ID FROM PUBLIC.TEST1 /* PUBLIC.TEST1.tableScan */ INNER JOIN PUBLIC.TEST2 /* PUBLIC.PRIMARY_KEY_4C: ID = TEST1.ID AND ID = TEST1.ID */ ON 1=1 /* WHERE TEST1.ID = TEST2.ID */ LEFT OUTER JOIN PUBLIC.TEST3 /* PUBLIC.PRIMARY_KEY_4C0: ID = TEST2.ID AND ID IS NULL */ ON TEST2.ID = TEST3.ID WHERE (TEST3.ID IS NULL) AND (TEST1.ID = TEST2.ID)
> -----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
> SELECT TEST1.ID, TEST2.ID, TEST3.ID FROM PUBLIC.TEST1 /* PUBLIC.TEST1.tableScan */ INNER JOIN PUBLIC.TEST2 /* PUBLIC.PRIMARY_KEY_4C: ID = TEST1.ID AND ID = TEST1.ID */ ON 1=1 /* WHERE TEST1.ID = TEST2.ID */ LEFT OUTER JOIN PUBLIC.TEST3 /* PUBLIC.PRIMARY_KEY_4C0: ID = TEST2.ID */ ON TEST2.ID = TEST3.ID WHERE (TEST3.ID IS NULL) AND (TEST1.ID = TEST2.ID)
> rows: 1
insert into test1 select x from system_range(2, 1000);
......@@ -3141,8 +3156,8 @@ inner join test2 on test1.id=test2.id
left outer join test3 on test2.id=test3.id
where test3.id is null;
> PLAN
> -----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
> SELECT TEST1.ID, TEST2.ID, TEST3.ID FROM PUBLIC.TEST2 /* PUBLIC.TEST2.tableScan */ LEFT OUTER JOIN PUBLIC.TEST3 /* PUBLIC.PRIMARY_KEY_4C0: ID = TEST2.ID AND ID IS NULL */ ON TEST2.ID = TEST3.ID INNER JOIN PUBLIC.TEST1 /* PUBLIC.PRIMARY_KEY_4: ID = TEST2.ID */ ON 1=1 WHERE (TEST3.ID IS NULL) AND (TEST1.ID = TEST2.ID)
> --------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
> SELECT TEST1.ID, TEST2.ID, TEST3.ID FROM PUBLIC.TEST2 /* PUBLIC.TEST2.tableScan */ LEFT OUTER JOIN PUBLIC.TEST3 /* PUBLIC.PRIMARY_KEY_4C0: ID = TEST2.ID */ ON TEST2.ID = TEST3.ID INNER JOIN PUBLIC.TEST1 /* PUBLIC.PRIMARY_KEY_4: ID = TEST2.ID */ ON 1=1 WHERE (TEST3.ID IS NULL) AND (TEST1.ID = TEST2.ID)
> rows: 1
SELECT TEST1.ID, TEST2.ID, TEST3.ID
......
Markdown 格式
0%
您添加了 0 到此讨论。请谨慎行事。
请先完成此评论的编辑!
注册 或者 后发表评论