提交 4f73254a authored 作者: Evgenij Ryazanov's avatar Evgenij Ryazanov

Add optimized implementation of MEDIAN aggregate for cases with indexed columns with nulls first

上级 ed2b0249
...@@ -20,6 +20,7 @@ import org.h2.result.SearchRow; ...@@ -20,6 +20,7 @@ import org.h2.result.SearchRow;
import org.h2.result.SortOrder; import org.h2.result.SortOrder;
import org.h2.table.Column; import org.h2.table.Column;
import org.h2.table.ColumnResolver; import org.h2.table.ColumnResolver;
import org.h2.table.IndexColumn;
import org.h2.table.Table; import org.h2.table.Table;
import org.h2.table.TableFilter; import org.h2.table.TableFilter;
import org.h2.util.StatementBuilder; import org.h2.util.StatementBuilder;
...@@ -293,7 +294,7 @@ public class Aggregate extends Expression { ...@@ -293,7 +294,7 @@ public class Aggregate extends Expression {
Table table = select.getTopTableFilter().getTable(); Table table = select.getTopTableFilter().getTable();
return ValueLong.get(table.getRowCount(session)); return ValueLong.get(table.getRowCount(session));
case MIN: case MIN:
case MAX: case MAX: {
boolean first = type == AggregateType.MIN; boolean first = type == AggregateType.MIN;
Index index = getMinMaxColumnIndex(); Index index = getMinMaxColumnIndex();
int sortType = index.getIndexColumns()[0].sortType; int sortType = index.getIndexColumns()[0].sortType;
...@@ -309,6 +310,54 @@ public class Aggregate extends Expression { ...@@ -309,6 +310,54 @@ public class Aggregate extends Expression {
v = row.getValue(index.getColumns()[0].getColumnId()); v = row.getValue(index.getColumns()[0].getColumnId());
} }
return v; return v;
}
case MEDIAN: {
Index index = getMinMaxColumnIndex();
long count = index.getRowCount(session);
if (count == 0) {
return ValueNull.INSTANCE;
}
Cursor cursor = index.find(session, null, null);
cursor.next();
// Skip nulls
SearchRow row;
while (count > 0) {
row = cursor.getSearchRow();
if (row == null) {
return ValueNull.INSTANCE;
}
if (row.getValue(index.getColumns()[0].getColumnId()) == ValueNull.INSTANCE) {
count--;
cursor.next();
} else
break;
}
if (count == 0) {
return ValueNull.INSTANCE;
}
long skip = (count - 1) / 2;
for (int i = 0; i < skip; i++) {
cursor.next();
row = cursor.getSearchRow();
}
row = cursor.getSearchRow();
Value v;
if (row == null) {
v = ValueNull.INSTANCE;
} else {
v = row.getValue(index.getColumns()[0].getColumnId());
}
if ((count & 1) == 0) {
cursor.next();
row = cursor.getSearchRow();
if (row == null) {
return v;
}
Value v2 = row.getValue(index.getColumns()[0].getColumnId());
return AggregateDataMedian.getMedian(v, v2, dataType, session.getDatabase().getCompareMode());
}
return v;
}
default: default:
DbException.throwInternalError("type=" + type); DbException.throwInternalError("type=" + type);
} }
...@@ -616,6 +665,29 @@ public class Aggregate extends Expression { ...@@ -616,6 +665,29 @@ public class Aggregate extends Expression {
case MAX: case MAX:
Index index = getMinMaxColumnIndex(); Index index = getMinMaxColumnIndex();
return index != null; return index != null;
case MEDIAN:
if (distinct) {
return false;
}
index = getMinMaxColumnIndex();
if (index == null) {
return false;
}
IndexColumn ic = index.getIndexColumns()[0];
if (!ic.column.isNullable()) {
return true;
}
int sortType = ic.sortType;
// Nulls last is not supported
if ((sortType & SortOrder.NULLS_LAST) != 0)
return false;
// Ascending is supported
if ((sortType & SortOrder.DESCENDING) == 0)
return true;
// Descending with nulls first is also supported
if ((sortType & SortOrder.NULLS_FIRST) != 0)
return true;
return false;
default: default:
return false; return false;
} }
......
...@@ -68,7 +68,10 @@ class AggregateDataMedian extends AggregateData { ...@@ -68,7 +68,10 @@ class AggregateDataMedian extends AggregateData {
if ((len & 1) == 1) { if ((len & 1) == 1) {
return v1.convertTo(dataType); return v1.convertTo(dataType);
} }
Value v0 = a[idx - 1]; return getMedian(a[idx - 1], v1, dataType, mode);
}
static Value getMedian(Value v0, Value v1, int dataType, CompareMode mode) {
if (v0.compareTo(v1, mode) == 0) { if (v0.compareTo(v1, mode) == 0) {
return v1.convertTo(dataType); return v1.convertTo(dataType);
} }
......
...@@ -3,6 +3,240 @@ ...@@ -3,6 +3,240 @@
-- Initial Developer: H2 Group -- Initial Developer: H2 Group
-- --
-- ASC
create table test(v tinyint);
> ok
create index test_idx on test(v asc);
> ok
insert into test values (20), (20), (10);
> update count: 3
select median(v) from test;
> MEDIAN(V)
> ---------
> 20
insert into test values (null);
> update count: 1
select median(v) from test;
> MEDIAN(V)
> ---------
> 20
select median(distinct v) from test;
> MEDIAN(DISTINCT V)
> ------------------
> 15
insert into test values (10);
> update count: 1
select median(v) from test;
> MEDIAN(V)
> ---------
> 15
drop table test;
> ok
-- ASC NULLS FIRST
create table test(v tinyint);
> ok
create index test_idx on test(v asc nulls first);
> ok
insert into test values (20), (20), (10);
> update count: 3
select median(v) from test;
> MEDIAN(V)
> ---------
> 20
insert into test values (null);
> update count: 1
select median(v) from test;
> MEDIAN(V)
> ---------
> 20
select median(distinct v) from test;
> MEDIAN(DISTINCT V)
> ------------------
> 15
insert into test values (10);
> update count: 1
select median(v) from test;
> MEDIAN(V)
> ---------
> 15
drop table test;
> ok
-- ASC NULLS LAST
create table test(v tinyint);
> ok
create index test_idx on test(v asc nulls last);
> ok
insert into test values (20), (20), (10);
> update count: 3
select median(v) from test;
> MEDIAN(V)
> ---------
> 20
insert into test values (null);
> update count: 1
select median(v) from test;
> MEDIAN(V)
> ---------
> 20
select median(distinct v) from test;
> MEDIAN(DISTINCT V)
> ------------------
> 15
insert into test values (10);
> update count: 1
select median(v) from test;
> MEDIAN(V)
> ---------
> 15
drop table test;
> ok
-- DESC
create table test(v tinyint);
> ok
create index test_idx on test(v desc);
> ok
insert into test values (20), (20), (10);
> update count: 3
select median(v) from test;
> MEDIAN(V)
> ---------
> 20
insert into test values (null);
> update count: 1
select median(v) from test;
> MEDIAN(V)
> ---------
> 20
select median(distinct v) from test;
> MEDIAN(DISTINCT V)
> ------------------
> 15
insert into test values (10);
> update count: 1
select median(v) from test;
> MEDIAN(V)
> ---------
> 15
drop table test;
> ok
-- DESC NULLS FIRST
create table test(v tinyint);
> ok
create index test_idx on test(v desc nulls first);
> ok
insert into test values (20), (20), (10);
> update count: 3
select median(v) from test;
> MEDIAN(V)
> ---------
> 20
insert into test values (null);
> update count: 1
select median(v) from test;
> MEDIAN(V)
> ---------
> 20
select median(distinct v) from test;
> MEDIAN(DISTINCT V)
> ------------------
> 15
insert into test values (10);
> update count: 1
select median(v) from test;
> MEDIAN(V)
> ---------
> 15
drop table test;
> ok
-- DESC NULLS LAST
create table test(v tinyint);
> ok
create index test_idx on test(v desc nulls last);
> ok
insert into test values (20), (20), (10);
> update count: 3
select median(v) from test;
> MEDIAN(V)
> ---------
> 20
insert into test values (null);
> update count: 1
select median(v) from test;
> MEDIAN(V)
> ---------
> 20
select median(distinct v) from test;
> MEDIAN(DISTINCT V)
> ------------------
> 15
insert into test values (10);
> update count: 1
select median(v) from test;
> MEDIAN(V)
> ---------
> 15
drop table test;
> ok
create table test(v tinyint); create table test(v tinyint);
> ok > ok
......
Markdown 格式
0%
您添加了 0 到此讨论。请谨慎行事。
请先完成此评论的编辑!
注册 或者 后发表评论