提交 a50f8f5c authored 作者: Evgenij Ryazanov's avatar Evgenij Ryazanov

Add PERCENTILE_DISC inverse distribution function

上级 e1e6689d
...@@ -3674,6 +3674,22 @@ Aggregates are only allowed in select statements. ...@@ -3674,6 +3674,22 @@ Aggregates are only allowed in select statements.
VAR_SAMP(X) VAR_SAMP(X)
" "
"Functions (Aggregate)","PERCENTILE_DISC","
PERCENTILE_DISC(numeric) WITHIN GROUP (ORDER BY value [ASC|DESC])
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
","
Return percentile of values from the group.
Interpolation is not performed.
Argument must be between 0 and 1 inclusive.
Argument must be the same for all rows in the same group.
If argument is NULL, the result is NULL.
NULL values are ignored in the calculation.
If no rows are selected, the result is NULL.
Aggregates are only allowed in select statements.
","
PERCENTILE_DISC(0.5) WITHIN GROUP (ORDER BY V)
"
"Functions (Aggregate)","MEDIAN"," "Functions (Aggregate)","MEDIAN","
MEDIAN( [ DISTINCT|ALL ] value ) MEDIAN( [ DISTINCT|ALL ] value )
[FILTER (WHERE expression)] [OVER windowNameOrSpecification] [FILTER (WHERE expression)] [OVER windowNameOrSpecification]
......
...@@ -3084,6 +3084,12 @@ public class Parser { ...@@ -3084,6 +3084,12 @@ public class Parser {
} }
break; break;
} }
case PERCENTILE_DISC: {
Expression num = readExpression();
read(CLOSE_PAREN);
r = readWithinGroup(aggregateType, num);
break;
}
case MODE: { case MODE: {
if (readIf(CLOSE_PAREN)) { if (readIf(CLOSE_PAREN)) {
r = readWithinGroup(AggregateType.MODE, null); r = readWithinGroup(AggregateType.MODE, null);
......
...@@ -111,6 +111,7 @@ public class Aggregate extends AbstractAggregate { ...@@ -111,6 +111,7 @@ public class Aggregate extends AbstractAggregate {
addAggregate("HISTOGRAM", AggregateType.HISTOGRAM); addAggregate("HISTOGRAM", AggregateType.HISTOGRAM);
addAggregate("BIT_OR", AggregateType.BIT_OR); addAggregate("BIT_OR", AggregateType.BIT_OR);
addAggregate("BIT_AND", AggregateType.BIT_AND); addAggregate("BIT_AND", AggregateType.BIT_AND);
addAggregate("PERCENTILE_DISC", AggregateType.PERCENTILE_DISC);
addAggregate("MEDIAN", AggregateType.MEDIAN); addAggregate("MEDIAN", AggregateType.MEDIAN);
addAggregate("ARRAY_AGG", AggregateType.ARRAY_AGG); addAggregate("ARRAY_AGG", AggregateType.ARRAY_AGG);
addAggregate("MODE", AggregateType.MODE); addAggregate("MODE", AggregateType.MODE);
...@@ -198,6 +199,10 @@ public class Aggregate extends AbstractAggregate { ...@@ -198,6 +199,10 @@ public class Aggregate extends AbstractAggregate {
v = updateCollecting(session, v, remembered); v = updateCollecting(session, v, remembered);
} }
break; break;
case PERCENTILE_DISC:
((AggregateDataCollecting) data).setSharedArgument(v);
v = remembered != null ? remembered[1] : orderByList.get(0).expression.getValue(session);
break;
case MODE: case MODE:
v = remembered != null ? remembered[0] : orderByList.get(0).expression.getValue(session); v = remembered != null ? remembered[0] : orderByList.get(0).expression.getValue(session);
break; break;
...@@ -309,8 +314,21 @@ public class Aggregate extends AbstractAggregate { ...@@ -309,8 +314,21 @@ public class Aggregate extends AbstractAggregate {
} }
return v; return v;
} }
case PERCENTILE_DISC: {
Value v = on.getValue(session);
if (v == ValueNull.INSTANCE) {
return ValueNull.INSTANCE;
}
double arg = v.getDouble();
if (arg >= 0d && arg <= 1d) {
return Percentile.getFromIndex(session, orderByList.get(0).expression, type.getValueType(),
orderByList, arg, false);
} else {
throw DbException.getInvalidValueException("PERCENTILE_DISC argument", arg);
}
}
case MEDIAN: case MEDIAN:
return AggregateMedian.medianFromIndex(session, on, type.getValueType()); return Percentile.getFromIndex(session, on, type.getValueType(), orderByList, 0.5d, true);
case ENVELOPE: case ENVELOPE:
return ((MVSpatialIndex) AggregateDataEnvelope.getGeometryColumnIndex(on)).getBounds(session); return ((MVSpatialIndex) AggregateDataEnvelope.getGeometryColumnIndex(on)).getBounds(session);
default: default:
...@@ -369,12 +387,29 @@ public class Aggregate extends AbstractAggregate { ...@@ -369,12 +387,29 @@ public class Aggregate extends AbstractAggregate {
} }
return ValueArray.get(array); return ValueArray.get(array);
} }
case PERCENTILE_DISC: {
AggregateDataCollecting collectingData = (AggregateDataCollecting) data;
Value[] array = collectingData.getArray();
if (array == null) {
return ValueNull.INSTANCE;
}
Value v = collectingData.getSharedArgument();
if (v == ValueNull.INSTANCE) {
return ValueNull.INSTANCE;
}
double arg = v.getDouble();
if (arg >= 0d && arg <= 1d) {
return Percentile.getValue(session.getDatabase(), array, type.getValueType(), orderByList, arg, false);
} else {
throw DbException.getInvalidValueException("PERCENTILE_DISC argument", arg);
}
}
case MEDIAN: { case MEDIAN: {
Value[] array = ((AggregateDataCollecting) data).getArray(); Value[] array = ((AggregateDataCollecting) data).getArray();
if (array == null) { if (array == null) {
return ValueNull.INSTANCE; return ValueNull.INSTANCE;
} }
return AggregateMedian.median(session.getDatabase(), array, type.getValueType()); return Percentile.getValue(session.getDatabase(), array, type.getValueType(), orderByList, 0.5d, true);
} }
case MODE: case MODE:
return getMode(session, data); return getMode(session, data);
...@@ -549,6 +584,7 @@ public class Aggregate extends AbstractAggregate { ...@@ -549,6 +584,7 @@ public class Aggregate extends AbstractAggregate {
case MAX: case MAX:
case MEDIAN: case MEDIAN:
break; break;
case PERCENTILE_DISC:
case MODE: case MODE:
type = orderByList.get(0).expression.getType(); type = orderByList.get(0).expression.getType();
break; break;
...@@ -675,6 +711,9 @@ public class Aggregate extends AbstractAggregate { ...@@ -675,6 +711,9 @@ public class Aggregate extends AbstractAggregate {
case BIT_OR: case BIT_OR:
text = "BIT_OR"; text = "BIT_OR";
break; break;
case PERCENTILE_DISC:
text = "PERCENTILE_DISC";
break;
case MEDIAN: case MEDIAN:
text = "MEDIAN"; text = "MEDIAN";
break; break;
...@@ -746,11 +785,13 @@ public class Aggregate extends AbstractAggregate { ...@@ -746,11 +785,13 @@ public class Aggregate extends AbstractAggregate {
case MAX: case MAX:
Index index = getMinMaxColumnIndex(); Index index = getMinMaxColumnIndex();
return index != null; return index != null;
case PERCENTILE_DISC:
return on.isConstant() && Percentile.getColumnIndex(orderByList.get(0).expression) != null;
case MEDIAN: case MEDIAN:
if (distinct) { if (distinct) {
return false; return false;
} }
return AggregateMedian.getMedianColumnIndex(on) != null; return Percentile.getColumnIndex(on) != null;
case ENVELOPE: case ENVELOPE:
return AggregateDataEnvelope.getGeometryColumnIndex(on) != null; return AggregateDataEnvelope.getGeometryColumnIndex(on) != null;
default: default:
......
...@@ -34,6 +34,7 @@ abstract class AggregateData { ...@@ -34,6 +34,7 @@ abstract class AggregateData {
break; break;
case GROUP_CONCAT: case GROUP_CONCAT:
case ARRAY_AGG: case ARRAY_AGG:
case PERCENTILE_DISC:
case MEDIAN: case MEDIAN:
break; break;
case MIN: case MIN:
......
...@@ -11,7 +11,9 @@ import java.util.Collections; ...@@ -11,7 +11,9 @@ import java.util.Collections;
import java.util.Iterator; import java.util.Iterator;
import java.util.TreeSet; import java.util.TreeSet;
import org.h2.api.ErrorCode;
import org.h2.engine.Database; import org.h2.engine.Database;
import org.h2.message.DbException;
import org.h2.value.Value; import org.h2.value.Value;
import org.h2.value.ValueNull; import org.h2.value.ValueNull;
...@@ -31,6 +33,8 @@ class AggregateDataCollecting extends AggregateData implements Iterable<Value> { ...@@ -31,6 +33,8 @@ class AggregateDataCollecting extends AggregateData implements Iterable<Value> {
Collection<Value> values; Collection<Value> values;
private Value shared;
/** /**
* Creates new instance of data for collecting aggregates. * Creates new instance of data for collecting aggregates.
* *
...@@ -84,4 +88,27 @@ class AggregateDataCollecting extends AggregateData implements Iterable<Value> { ...@@ -84,4 +88,27 @@ class AggregateDataCollecting extends AggregateData implements Iterable<Value> {
return values != null ? values.iterator() : Collections.<Value>emptyIterator(); return values != null ? values.iterator() : Collections.<Value>emptyIterator();
} }
/**
* Sets value of a shared argument.
*
* @param shared the shared value
*/
void setSharedArgument(Value shared) {
if (this.shared == null) {
this.shared = shared;
} else if (!this.shared.equals(shared)) {
throw DbException.get(ErrorCode.INVALID_VALUE_2, "Inverse distribution function argument",
this.shared.getTraceSQL() + "<>" + shared.getTraceSQL());
}
}
/**
* Returns value of a shared argument.
*
* @return value of a shared argument
*/
Value getSharedArgument() {
return shared;
}
} }
...@@ -95,6 +95,11 @@ public enum AggregateType { ...@@ -95,6 +95,11 @@ public enum AggregateType {
*/ */
HISTOGRAM, HISTOGRAM,
/**
* The aggregate type for PERCENTILE_DISC(expression).
*/
PERCENTILE_DISC,
/** /**
* The aggregate type for MEDIAN(expression). * The aggregate type for MEDIAN(expression).
*/ */
......
...@@ -10,6 +10,7 @@ import java.util.ArrayList; ...@@ -10,6 +10,7 @@ import java.util.ArrayList;
import java.util.Arrays; import java.util.Arrays;
import org.h2.api.IntervalQualifier; import org.h2.api.IntervalQualifier;
import org.h2.command.dml.SelectOrderBy;
import org.h2.engine.Database; import org.h2.engine.Database;
import org.h2.engine.Mode; import org.h2.engine.Mode;
import org.h2.engine.Session; import org.h2.engine.Session;
...@@ -41,25 +42,26 @@ import org.h2.value.ValueTimestamp; ...@@ -41,25 +42,26 @@ import org.h2.value.ValueTimestamp;
import org.h2.value.ValueTimestampTimeZone; import org.h2.value.ValueTimestampTimeZone;
/** /**
* MEDIAN aggregate. * PERCENTILE_DISC and MEDIAN inverse distribution functions.
*/ */
final class AggregateMedian { final class Percentile {
private static boolean isNullsLast(Index index) { private static boolean isNullsLast(Index index) {
IndexColumn ic = index.getIndexColumns()[0]; IndexColumn ic = index.getIndexColumns()[0];
int sortType = ic.sortType; int sortType = ic.sortType;
return (sortType & SortOrder.NULLS_LAST) != 0 return (sortType & SortOrder.NULLS_LAST) != 0
|| (sortType & SortOrder.NULLS_FIRST) == 0 || (sortType & SortOrder.NULLS_FIRST) == 0
&& ((sortType & SortOrder.DESCENDING) != 0 ^ SysProperties.SORT_NULLS_HIGH); && (sortType & SortOrder.DESCENDING) != 0 ^ SysProperties.SORT_NULLS_HIGH;
} }
/** /**
* Get the index (if any) for the column specified in the median aggregate. * Get the index (if any) for the column specified in the inverse
* distribution function.
* *
* @param on the expression (usually a column expression) * @param on the expression (usually a column expression)
* @return the index, or null * @return the index, or null
*/ */
static Index getMedianColumnIndex(Expression on) { static Index getColumnIndex(Expression on) {
if (on instanceof ExpressionColumn) { if (on instanceof ExpressionColumn) {
ExpressionColumn col = (ExpressionColumn) on; ExpressionColumn col = (ExpressionColumn) on;
Column column = col.getColumn(); Column column = col.getColumn();
...@@ -92,35 +94,64 @@ final class AggregateMedian { ...@@ -92,35 +94,64 @@ final class AggregateMedian {
} }
/** /**
* Get the median from the array of values. * Get the result from the array of values.
* *
* @param database the database * @param database the database
* @param array array with values * @param array array with values
* @param dataType the data type * @param dataType the data type
* @param orderByList ORDER BY list
* @param percentile argument of percentile function, or 0.5d for median
* @param interpolate whether value should be interpolated
* @return the result * @return the result
*/ */
static Value median(Database database, Value[] array, int dataType) { static Value getValue(Database database, Value[] array, int dataType, ArrayList<SelectOrderBy> orderByList,
double percentile, boolean interpolate) {
final CompareMode compareMode = database.getCompareMode(); final CompareMode compareMode = database.getCompareMode();
Arrays.sort(array, compareMode); Arrays.sort(array, compareMode);
int len = array.length; int count = array.length;
int idx = len / 2; boolean reverseIndex = orderByList != null && (orderByList.get(0).sortType & SortOrder.DESCENDING) != 0;
Value v1 = array[idx]; double fpRow = (count - 1) * percentile;
if ((len & 1) == 1) { int rowIdx1 = (int) fpRow;
return v1.convertTo(dataType); double factor = fpRow - rowIdx1;
int rowIdx2;
if (factor == 0d) {
interpolate = false;
rowIdx2 = rowIdx1;
} else {
rowIdx2 = rowIdx1 + 1;
if (!interpolate) {
if (factor > 0.5d) {
rowIdx1 = rowIdx2;
} else {
rowIdx2 = rowIdx1;
}
}
} }
return getMedian(array[idx - 1], v1, dataType, database.getMode(), compareMode); if (reverseIndex) {
rowIdx1 = count - 1 - rowIdx1;
rowIdx2 = count - 1 - rowIdx2;
}
Value v = array[rowIdx1];
if (!interpolate) {
return v.convertTo(dataType);
}
return getMedian(v, array[rowIdx2], dataType, database.getMode(), compareMode);
} }
/** /**
* Get the median from the index. * Get the result from the index.
* *
* @param session the session * @param session the session
* @param on the expression * @param expression the expression
* @param dataType the data type * @param dataType the data type
* @param orderByList ORDER BY list
* @param percentile argument of percentile function, or 0.5d for median
* @param interpolate whether value should be interpolated
* @return the result * @return the result
*/ */
static Value medianFromIndex(Session session, Expression on, int dataType) { static Value getFromIndex(Session session, Expression expression, int dataType,
Index index = getMedianColumnIndex(on); ArrayList<SelectOrderBy> orderByList, double percentile, boolean interpolate) {
Index index = getColumnIndex(expression);
long count = index.getRowCount(session); long count = index.getRowCount(session);
if (count == 0) { if (count == 0) {
return ValueNull.INSTANCE; return ValueNull.INSTANCE;
...@@ -128,7 +159,7 @@ final class AggregateMedian { ...@@ -128,7 +159,7 @@ final class AggregateMedian {
Cursor cursor = index.find(session, null, null); Cursor cursor = index.find(session, null, null);
cursor.next(); cursor.next();
int columnId = index.getColumns()[0].getColumnId(); int columnId = index.getColumns()[0].getColumnId();
ExpressionColumn expr = (ExpressionColumn) on; ExpressionColumn expr = (ExpressionColumn) expression;
if (expr.getColumn().isNullable()) { if (expr.getColumn().isNullable()) {
boolean hasNulls = false; boolean hasNulls = false;
SearchRow row; SearchRow row;
...@@ -165,7 +196,26 @@ final class AggregateMedian { ...@@ -165,7 +196,26 @@ final class AggregateMedian {
} }
} }
} }
long skip = (count - 1) / 2; boolean reverseIndex = (orderByList != null ? orderByList.get(0).sortType & SortOrder.DESCENDING : 0)
!= (index.getIndexColumns()[0].sortType & SortOrder.DESCENDING);
double fpRow = (count - 1) * percentile;
long rowIdx1 = (long) fpRow;
double factor = fpRow - rowIdx1;
long rowIdx2;
if (factor == 0d) {
interpolate = false;
rowIdx2 = rowIdx1;
} else {
rowIdx2 = rowIdx1 + 1;
if (!interpolate) {
if (factor > 0.5d) {
rowIdx1 = rowIdx2;
} else {
rowIdx2 = rowIdx1;
}
}
}
long skip = reverseIndex ? count - 1 - rowIdx2 : rowIdx1;
for (int i = 0; i < skip; i++) { for (int i = 0; i < skip; i++) {
cursor.next(); cursor.next();
} }
...@@ -177,7 +227,7 @@ final class AggregateMedian { ...@@ -177,7 +227,7 @@ final class AggregateMedian {
if (v == ValueNull.INSTANCE) { if (v == ValueNull.INSTANCE) {
return v; return v;
} }
if ((count & 1) == 0) { if (interpolate) {
cursor.next(); cursor.next();
row = cursor.getSearchRow(); row = cursor.getSearchRow();
if (row == null) { if (row == null) {
...@@ -188,14 +238,18 @@ final class AggregateMedian { ...@@ -188,14 +238,18 @@ final class AggregateMedian {
return v; return v;
} }
Database database = session.getDatabase(); Database database = session.getDatabase();
if (reverseIndex) {
Value t = v;
v = v2;
v2 = t;
}
return getMedian(v, v2, dataType, database.getMode(), database.getCompareMode()); return getMedian(v, v2, dataType, database.getMode(), database.getCompareMode());
} }
return v; return v;
} }
private static Value getMedian(Value v0, Value v1, int dataType, Mode databaseMode, CompareMode compareMode) { private static Value getMedian(Value v0, Value v1, int dataType, Mode databaseMode, CompareMode compareMode) {
int cmp = v0.compareTo(v1, databaseMode, compareMode); if (v0.compareTo(v1, databaseMode, compareMode) == 0) {
if (cmp == 0) {
return v0.convertTo(dataType); return v0.convertTo(dataType);
} }
switch (dataType) { switch (dataType) {
...@@ -273,12 +327,12 @@ final class AggregateMedian { ...@@ -273,12 +327,12 @@ final class AggregateMedian {
IntervalUtils.intervalToAbsolute((ValueInterval) v0) IntervalUtils.intervalToAbsolute((ValueInterval) v0)
.add(IntervalUtils.intervalToAbsolute((ValueInterval) v1)).shiftRight(1)); .add(IntervalUtils.intervalToAbsolute((ValueInterval) v1)).shiftRight(1));
default: default:
// Just return smaller // Just return first
return (cmp < 0 ? v0 : v1).convertTo(dataType); return v0.convertTo(dataType);
} }
} }
private AggregateMedian() { private Percentile() {
} }
} }
...@@ -165,7 +165,7 @@ public class TestScript extends TestDb { ...@@ -165,7 +165,7 @@ public class TestScript extends TestDb {
testScript("other/" + s + ".sql"); testScript("other/" + s + ".sql");
} }
for (String s : new String[] { "any", "array-agg", "avg", "bit-and", "bit-or", "count", "envelope", for (String s : new String[] { "any", "array-agg", "avg", "bit-and", "bit-or", "count", "envelope",
"every", "group-concat", "histogram", "max", "median", "min", "mode", "selectivity", "stddev-pop", "every", "group-concat", "histogram", "max", "min", "mode", "percentile", "selectivity", "stddev-pop",
"stddev-samp", "sum", "var-pop", "var-samp" }) { "stddev-samp", "sum", "var-pop", "var-samp" }) {
testScript("functions/aggregate/" + s + ".sql"); testScript("functions/aggregate/" + s + ".sql");
} }
......
...@@ -13,14 +13,26 @@ create index test_idx on test(v asc); ...@@ -13,14 +13,26 @@ create index test_idx on test(v asc);
insert into test values (20), (20), (10); insert into test values (20), (20), (10);
> update count: 3 > update count: 3
select median(v) from test; select
>> 20 percentile_disc(0.5) within group (order by v) d50a,
percentile_disc(0.5) within group (order by v desc) d50d,
median(v) m from test;
> D50A D50D M
> ---- ---- --
> 20 20 20
> rows: 1
insert into test values (null); insert into test values (null);
> update count: 1 > update count: 1
select median(v) from test; select
>> 20 percentile_disc(0.5) within group (order by v) d50a,
percentile_disc(0.5) within group (order by v desc) d50d,
median(v) m from test;
> D50A D50D M
> ---- ---- --
> 20 20 20
> rows: 1
select median(distinct v) from test; select median(distinct v) from test;
>> 15 >> 15
...@@ -28,8 +40,14 @@ select median(distinct v) from test; ...@@ -28,8 +40,14 @@ select median(distinct v) from test;
insert into test values (10); insert into test values (10);
> update count: 1 > update count: 1
select median(v) from test; select
>> 15 percentile_disc(0.5) within group (order by v) d50a,
percentile_disc(0.5) within group (order by v desc) d50d,
median(v) m from test;
> D50A D50D M
> ---- ---- --
> 10 20 15
> rows: 1
drop table test; drop table test;
> ok > ok
...@@ -44,14 +62,26 @@ create index test_idx on test(v asc nulls first); ...@@ -44,14 +62,26 @@ create index test_idx on test(v asc nulls first);
insert into test values (20), (20), (10); insert into test values (20), (20), (10);
> update count: 3 > update count: 3
select median(v) from test; select
>> 20 percentile_disc(0.5) within group (order by v) d50a,
percentile_disc(0.5) within group (order by v desc) d50d,
median(v) m from test;
> D50A D50D M
> ---- ---- --
> 20 20 20
> rows: 1
insert into test values (null); insert into test values (null);
> update count: 1 > update count: 1
select median(v) from test; select
>> 20 percentile_disc(0.5) within group (order by v) d50a,
percentile_disc(0.5) within group (order by v desc) d50d,
median(v) m from test;
> D50A D50D M
> ---- ---- --
> 20 20 20
> rows: 1
select median(distinct v) from test; select median(distinct v) from test;
>> 15 >> 15
...@@ -59,8 +89,14 @@ select median(distinct v) from test; ...@@ -59,8 +89,14 @@ select median(distinct v) from test;
insert into test values (10); insert into test values (10);
> update count: 1 > update count: 1
select median(v) from test; select
>> 15 percentile_disc(0.5) within group (order by v) d50a,
percentile_disc(0.5) within group (order by v desc) d50d,
median(v) m from test;
> D50A D50D M
> ---- ---- --
> 10 20 15
> rows: 1
drop table test; drop table test;
> ok > ok
...@@ -75,14 +111,26 @@ create index test_idx on test(v asc nulls last); ...@@ -75,14 +111,26 @@ create index test_idx on test(v asc nulls last);
insert into test values (20), (20), (10); insert into test values (20), (20), (10);
> update count: 3 > update count: 3
select median(v) from test; select
>> 20 percentile_disc(0.5) within group (order by v) d50a,
percentile_disc(0.5) within group (order by v desc) d50d,
median(v) m from test;
> D50A D50D M
> ---- ---- --
> 20 20 20
> rows: 1
insert into test values (null); insert into test values (null);
> update count: 1 > update count: 1
select median(v) from test; select
>> 20 percentile_disc(0.5) within group (order by v) d50a,
percentile_disc(0.5) within group (order by v desc) d50d,
median(v) m from test;
> D50A D50D M
> ---- ---- --
> 20 20 20
> rows: 1
select median(distinct v) from test; select median(distinct v) from test;
>> 15 >> 15
...@@ -90,8 +138,14 @@ select median(distinct v) from test; ...@@ -90,8 +138,14 @@ select median(distinct v) from test;
insert into test values (10); insert into test values (10);
> update count: 1 > update count: 1
select median(v) from test; select
>> 15 percentile_disc(0.5) within group (order by v) d50a,
percentile_disc(0.5) within group (order by v desc) d50d,
median(v) m from test;
> D50A D50D M
> ---- ---- --
> 10 20 15
> rows: 1
drop table test; drop table test;
> ok > ok
...@@ -106,14 +160,26 @@ create index test_idx on test(v desc); ...@@ -106,14 +160,26 @@ create index test_idx on test(v desc);
insert into test values (20), (20), (10); insert into test values (20), (20), (10);
> update count: 3 > update count: 3
select median(v) from test; select
>> 20 percentile_disc(0.5) within group (order by v) d50a,
percentile_disc(0.5) within group (order by v desc) d50d,
median(v) m from test;
> D50A D50D M
> ---- ---- --
> 20 20 20
> rows: 1
insert into test values (null); insert into test values (null);
> update count: 1 > update count: 1
select median(v) from test; select
>> 20 percentile_disc(0.5) within group (order by v) d50a,
percentile_disc(0.5) within group (order by v desc) d50d,
median(v) m from test;
> D50A D50D M
> ---- ---- --
> 20 20 20
> rows: 1
select median(distinct v) from test; select median(distinct v) from test;
>> 15 >> 15
...@@ -121,8 +187,14 @@ select median(distinct v) from test; ...@@ -121,8 +187,14 @@ select median(distinct v) from test;
insert into test values (10); insert into test values (10);
> update count: 1 > update count: 1
select median(v) from test; select
>> 15 percentile_disc(0.5) within group (order by v) d50a,
percentile_disc(0.5) within group (order by v desc) d50d,
median(v) m from test;
> D50A D50D M
> ---- ---- --
> 10 20 15
> rows: 1
drop table test; drop table test;
> ok > ok
...@@ -137,14 +209,26 @@ create index test_idx on test(v desc nulls first); ...@@ -137,14 +209,26 @@ create index test_idx on test(v desc nulls first);
insert into test values (20), (20), (10); insert into test values (20), (20), (10);
> update count: 3 > update count: 3
select median(v) from test; select
>> 20 percentile_disc(0.5) within group (order by v) d50a,
percentile_disc(0.5) within group (order by v desc) d50d,
median(v) m from test;
> D50A D50D M
> ---- ---- --
> 20 20 20
> rows: 1
insert into test values (null); insert into test values (null);
> update count: 1 > update count: 1
select median(v) from test; select
>> 20 percentile_disc(0.5) within group (order by v) d50a,
percentile_disc(0.5) within group (order by v desc) d50d,
median(v) m from test;
> D50A D50D M
> ---- ---- --
> 20 20 20
> rows: 1
select median(distinct v) from test; select median(distinct v) from test;
>> 15 >> 15
...@@ -152,8 +236,14 @@ select median(distinct v) from test; ...@@ -152,8 +236,14 @@ select median(distinct v) from test;
insert into test values (10); insert into test values (10);
> update count: 1 > update count: 1
select median(v) from test; select
>> 15 percentile_disc(0.5) within group (order by v) d50a,
percentile_disc(0.5) within group (order by v desc) d50d,
median(v) m from test;
> D50A D50D M
> ---- ---- --
> 10 20 15
> rows: 1
drop table test; drop table test;
> ok > ok
...@@ -168,14 +258,26 @@ create index test_idx on test(v desc nulls last); ...@@ -168,14 +258,26 @@ create index test_idx on test(v desc nulls last);
insert into test values (20), (20), (10); insert into test values (20), (20), (10);
> update count: 3 > update count: 3
select median(v) from test; select
>> 20 percentile_disc(0.5) within group (order by v) d50a,
percentile_disc(0.5) within group (order by v desc) d50d,
median(v) m from test;
> D50A D50D M
> ---- ---- --
> 20 20 20
> rows: 1
insert into test values (null); insert into test values (null);
> update count: 1 > update count: 1
select median(v) from test; select
>> 20 percentile_disc(0.5) within group (order by v) d50a,
percentile_disc(0.5) within group (order by v desc) d50d,
median(v) m from test;
> D50A D50D M
> ---- ---- --
> 20 20 20
> rows: 1
select median(distinct v) from test; select median(distinct v) from test;
>> 15 >> 15
...@@ -183,8 +285,14 @@ select median(distinct v) from test; ...@@ -183,8 +285,14 @@ select median(distinct v) from test;
insert into test values (10); insert into test values (10);
> update count: 1 > update count: 1
select median(v) from test; select
>> 15 percentile_disc(0.5) within group (order by v) d50a,
percentile_disc(0.5) within group (order by v desc) d50d,
median(v) m from test;
> D50A D50D M
> ---- ---- --
> 10 20 15
> rows: 1
drop table test; drop table test;
> ok > ok
...@@ -665,3 +773,99 @@ select dept, median(amount) filter (where amount >= 20) from test ...@@ -665,3 +773,99 @@ select dept, median(amount) filter (where amount >= 20) from test
drop table test; drop table test;
> ok > ok
create table test(g int, v int);
> ok
insert into test values (1, 1), (1, 2), (1, 3), (1, 4), (1, 5), (1, 6), (1, 7), (1, 8), (1, 9), (1, 10),
(2, 10), (2, 20), (2, 30), (2, 100);
> update count: 14
select
percentile_disc(0.05) within group (order by v) d05a,
percentile_disc(0.05) within group (order by v desc) d05d,
percentile_disc(0.5) within group (order by v) d50,
percentile_disc(0.5) within group (order by v desc) d50d,
percentile_disc(0.95) within group (order by v) d95a,
percentile_disc(0.95) within group (order by v desc) d95d,
g from test group by g;
> D05A D05D D50 D50D D95A D95D G
> ---- ---- --- ---- ---- ---- -
> 1 10 5 6 10 1 1
> 10 100 20 30 100 10 2
> rows: 2
select
percentile_disc(0.05) within group (order by v) over (partition by g order by v) d05a,
percentile_disc(0.05) within group (order by v desc) over (partition by g order by v) d05d,
percentile_disc(0.5) within group (order by v) over (partition by g order by v) d50,
percentile_disc(0.5) within group (order by v desc) over (partition by g order by v) d50d,
percentile_disc(0.95) within group (order by v) over (partition by g order by v) d95a,
percentile_disc(0.95) within group (order by v desc) over (partition by g order by v) d95d,
g, v from test order by g, v;
> D05A D05D D50 D50D D95A D95D G V
> ---- ---- --- ---- ---- ---- - ---
> 1 1 1 1 1 1 1 1
> 1 2 1 2 2 1 1 2
> 1 3 2 2 3 1 1 3
> 1 4 2 3 4 1 1 4
> 1 5 3 3 5 1 1 5
> 1 6 3 4 6 1 1 6
> 1 7 4 4 7 1 1 7
> 1 8 4 5 8 1 1 8
> 1 9 5 5 9 1 1 9
> 1 10 5 6 10 1 1 10
> 10 10 10 10 10 10 2 10
> 10 20 10 20 20 10 2 20
> 10 30 20 20 30 10 2 30
> 10 100 20 30 100 10 2 100
> rows (ordered): 14
delete from test where g <> 1;
> update count: 4
create index test_idx on test(v);
> ok
select
percentile_disc(0.05) within group (order by v) d05a,
percentile_disc(0.05) within group (order by v desc) d05d,
percentile_disc(0.5) within group (order by v) d50,
percentile_disc(0.5) within group (order by v desc) d50d,
percentile_disc(0.95) within group (order by v) d95a,
percentile_disc(0.95) within group (order by v desc) d95d
from test;
> D05A D05D D50 D50D D95A D95D
> ---- ---- --- ---- ---- ----
> 1 10 5 6 10 1
> rows: 1
SELECT percentile_disc(null) within group (order by v) from test;
>> null
SELECT percentile_disc(-0.01) within group (order by v) from test;
> exception INVALID_VALUE_2
SELECT percentile_disc(1.01) within group (order by v) from test;
> exception INVALID_VALUE_2
SELECT percentile_disc(v) within group (order by v) from test;
> exception INVALID_VALUE_2
drop index test_idx;
> ok
SELECT percentile_disc(null) within group (order by v) from test;
>> null
SELECT percentile_disc(-0.01) within group (order by v) from test;
> exception INVALID_VALUE_2
SELECT percentile_disc(1.01) within group (order by v) from test;
> exception INVALID_VALUE_2
SELECT percentile_disc(v) within group (order by v) from test;
> exception INVALID_VALUE_2
drop table test;
> ok
Markdown 格式
0%
您添加了 0 到此讨论。请谨慎行事。
请先完成此评论的编辑!
注册 或者 后发表评论