SQL: TRUNCATE and ROUND functions (#33779)

* Added TRUNCATE function, modified ROUND to accept two parameters instead of one. Made the second parameter optional for both functions.
* Added documentation for both functions.
This commit is contained in:
Andrei Stefan 2018-09-20 15:29:53 +03:00 committed by GitHub
parent 168a0b23fe
commit 6fb7e49b22
No known key found for this signature in database
GPG Key ID: 4AEE18F83AFDEB23
18 changed files with 652 additions and 105 deletions

View File

@ -37,13 +37,19 @@ Same as `CEIL`
https://en.wikipedia.org/wiki/E_%28mathematical_constant%29[Euler's number], returns `2.7182818284590452354` https://en.wikipedia.org/wiki/E_%28mathematical_constant%29[Euler's number], returns `2.7182818284590452354`
* https://en.wikipedia.org/wiki/Exponential_function[e^x^] (`EXP`)
* https://en.wikipedia.org/wiki/Rounding#Round_half_up[Round] (`ROUND`) ["source","sql",subs="attributes,callouts,macros"]
--------------------------------------------------
include-tagged::{sql-specs}/math.sql-spec[exp]
--------------------------------------------------
// TODO make the example in the tests presentable * https://docs.oracle.com/javase/8/docs/api/java/lang/Math.html#expm1-double-[e^x^ - 1] (`EXPM1`)
NOTE: This rounds "half up" meaning that `ROUND(-1.5)` results in `-1`.
["source","sql",subs="attributes,callouts,macros"]
--------------------------------------------------
include-tagged::{sql-specs}/math.sql-spec[expm1]
--------------------------------------------------
* https://en.wikipedia.org/wiki/Floor_and_ceiling_functions[Floor] (`FLOOR`) * https://en.wikipedia.org/wiki/Floor_and_ceiling_functions[Floor] (`FLOOR`)
@ -63,6 +69,36 @@ include-tagged::{sql-specs}/math.sql-spec[log]
include-tagged::{sql-specs}/math.sql-spec[log10] include-tagged::{sql-specs}/math.sql-spec[log10]
-------------------------------------------------- --------------------------------------------------
* `ROUND`
.Synopsis:
[source, sql]
----
ROUND(numeric_exp<1>[, integer_exp<2>])
----
*Input*:
<1> numeric expression
<2> integer expression; optional
*Output*: numeric
.Description:
Returns `numeric_exp` rounded to `integer_exp` places right of the decimal point. If `integer_exp` is negative,
`numeric_exp` is rounded to |`integer_exp`| places to the left of the decimal point. If `integer_exp` is omitted,
the function will perform as if `integer_exp` would be 0. The returned numeric data type is the same as the data type
of `numeric_exp`.
["source","sql",subs="attributes,callouts,macros"]
--------------------------------------------------
include-tagged::{sql-specs}/docs.csv-spec[mathRoundWithPositiveParameter]
--------------------------------------------------
["source","sql",subs="attributes,callouts,macros"]
--------------------------------------------------
include-tagged::{sql-specs}/docs.csv-spec[mathRoundWithNegativeParameter]
--------------------------------------------------
* https://en.wikipedia.org/wiki/Square_root[Square root] (`SQRT`) * https://en.wikipedia.org/wiki/Square_root[Square root] (`SQRT`)
["source","sql",subs="attributes,callouts,macros"] ["source","sql",subs="attributes,callouts,macros"]
@ -70,18 +106,34 @@ include-tagged::{sql-specs}/math.sql-spec[log10]
include-tagged::{sql-specs}/math.sql-spec[sqrt] include-tagged::{sql-specs}/math.sql-spec[sqrt]
-------------------------------------------------- --------------------------------------------------
* https://en.wikipedia.org/wiki/Exponential_function[e^x^] (`EXP`) * `TRUNCATE`
.Synopsis:
[source, sql]
----
TRUNCATE(numeric_exp<1>[, integer_exp<2>])
----
*Input*:
<1> numeric expression
<2> integer expression; optional
*Output*: numeric
.Description:
Returns `numeric_exp` truncated to `integer_exp` places right of the decimal point. If `integer_exp` is negative,
`numeric_exp` is truncated to |`integer_exp`| places to the left of the decimal point. If `integer_exp` is omitted,
the function will perform as if `integer_exp` would be 0. The returned numeric data type is the same as the data type
of `numeric_exp`.
["source","sql",subs="attributes,callouts,macros"] ["source","sql",subs="attributes,callouts,macros"]
-------------------------------------------------- --------------------------------------------------
include-tagged::{sql-specs}/math.sql-spec[exp] include-tagged::{sql-specs}/docs.csv-spec[mathTruncateWithPositiveParameter]
-------------------------------------------------- --------------------------------------------------
* https://docs.oracle.com/javase/8/docs/api/java/lang/Math.html#expm1-double-[e^x^ - 1] (`EXPM1`)
["source","sql",subs="attributes,callouts,macros"] ["source","sql",subs="attributes,callouts,macros"]
-------------------------------------------------- --------------------------------------------------
include-tagged::{sql-specs}/math.sql-spec[expm1] include-tagged::{sql-specs}/docs.csv-spec[mathTruncateWithNegativeParameter]
-------------------------------------------------- --------------------------------------------------
==== Trigonometric ==== Trigonometric

View File

@ -190,7 +190,7 @@ class JdbcDatabaseMetaData implements DatabaseMetaData, JdbcWrapper {
+ "PI,POWER," + "PI,POWER,"
+ "RADIANS,RAND,ROUND," + "RADIANS,RAND,ROUND,"
+ "SIGN,SIN,SQRT," + "SIGN,SIN,SQRT,"
+ "TAN"; + "TAN,TRUNCATE";
} }
@Override @Override

View File

@ -61,6 +61,7 @@ import org.elasticsearch.xpack.sql.expression.function.scalar.math.Sin;
import org.elasticsearch.xpack.sql.expression.function.scalar.math.Sinh; import org.elasticsearch.xpack.sql.expression.function.scalar.math.Sinh;
import org.elasticsearch.xpack.sql.expression.function.scalar.math.Sqrt; import org.elasticsearch.xpack.sql.expression.function.scalar.math.Sqrt;
import org.elasticsearch.xpack.sql.expression.function.scalar.math.Tan; import org.elasticsearch.xpack.sql.expression.function.scalar.math.Tan;
import org.elasticsearch.xpack.sql.expression.function.scalar.math.Truncate;
import org.elasticsearch.xpack.sql.expression.function.scalar.string.Ascii; import org.elasticsearch.xpack.sql.expression.function.scalar.string.Ascii;
import org.elasticsearch.xpack.sql.expression.function.scalar.string.BitLength; import org.elasticsearch.xpack.sql.expression.function.scalar.string.BitLength;
import org.elasticsearch.xpack.sql.expression.function.scalar.string.Char; import org.elasticsearch.xpack.sql.expression.function.scalar.string.Char;
@ -114,21 +115,21 @@ public class FunctionRegistry {
def(SumOfSquares.class, SumOfSquares::new), def(SumOfSquares.class, SumOfSquares::new),
def(Skewness.class, Skewness::new), def(Skewness.class, Skewness::new),
def(Kurtosis.class, Kurtosis::new), def(Kurtosis.class, Kurtosis::new),
// Scalar functions // Scalar functions
// Date // Date
def(DayName.class, DayName::new, "DAYNAME"),
def(DayOfMonth.class, DayOfMonth::new, "DAYOFMONTH", "DAY", "DOM"), def(DayOfMonth.class, DayOfMonth::new, "DAYOFMONTH", "DAY", "DOM"),
def(DayOfWeek.class, DayOfWeek::new, "DAYOFWEEK", "DOW"), def(DayOfWeek.class, DayOfWeek::new, "DAYOFWEEK", "DOW"),
def(DayOfYear.class, DayOfYear::new, "DAYOFYEAR", "DOY"), def(DayOfYear.class, DayOfYear::new, "DAYOFYEAR", "DOY"),
def(HourOfDay.class, HourOfDay::new, "HOUR"), def(HourOfDay.class, HourOfDay::new, "HOUR"),
def(MinuteOfDay.class, MinuteOfDay::new), def(MinuteOfDay.class, MinuteOfDay::new),
def(MinuteOfHour.class, MinuteOfHour::new, "MINUTE"), def(MinuteOfHour.class, MinuteOfHour::new, "MINUTE"),
def(SecondOfMinute.class, SecondOfMinute::new, "SECOND"), def(MonthName.class, MonthName::new, "MONTHNAME"),
def(MonthOfYear.class, MonthOfYear::new, "MONTH"), def(MonthOfYear.class, MonthOfYear::new, "MONTH"),
def(SecondOfMinute.class, SecondOfMinute::new, "SECOND"),
def(Quarter.class, Quarter::new),
def(Year.class, Year::new), def(Year.class, Year::new),
def(WeekOfYear.class, WeekOfYear::new, "WEEK"), def(WeekOfYear.class, WeekOfYear::new, "WEEK"),
def(DayName.class, DayName::new, "DAYNAME"),
def(MonthName.class, MonthName::new, "MONTHNAME"),
def(Quarter.class, Quarter::new),
// Math // Math
def(Abs.class, Abs::new), def(Abs.class, Abs::new),
def(ACos.class, ACos::new), def(ACos.class, ACos::new),
@ -159,27 +160,28 @@ public class FunctionRegistry {
def(Sinh.class, Sinh::new), def(Sinh.class, Sinh::new),
def(Sqrt.class, Sqrt::new), def(Sqrt.class, Sqrt::new),
def(Tan.class, Tan::new), def(Tan.class, Tan::new),
def(Truncate.class, Truncate::new),
// String // String
def(Ascii.class, Ascii::new), def(Ascii.class, Ascii::new),
def(Char.class, Char::new),
def(BitLength.class, BitLength::new), def(BitLength.class, BitLength::new),
def(Char.class, Char::new),
def(CharLength.class, CharLength::new, "CHARACTER_LENGTH"), def(CharLength.class, CharLength::new, "CHARACTER_LENGTH"),
def(LCase.class, LCase::new),
def(Length.class, Length::new),
def(LTrim.class, LTrim::new),
def(RTrim.class, RTrim::new),
def(Space.class, Space::new),
def(Concat.class, Concat::new), def(Concat.class, Concat::new),
def(Insert.class, Insert::new), def(Insert.class, Insert::new),
def(LCase.class, LCase::new),
def(Left.class, Left::new), def(Left.class, Left::new),
def(Length.class, Length::new),
def(Locate.class, Locate::new), def(Locate.class, Locate::new),
def(LTrim.class, LTrim::new),
def(Position.class, Position::new), def(Position.class, Position::new),
def(Repeat.class, Repeat::new), def(Repeat.class, Repeat::new),
def(Replace.class, Replace::new), def(Replace.class, Replace::new),
def(Right.class, Right::new), def(Right.class, Right::new),
def(RTrim.class, RTrim::new),
def(Space.class, Space::new),
def(Substring.class, Substring::new), def(Substring.class, Substring::new),
def(UCase.class, UCase::new), def(UCase.class, UCase::new),
// Special // Special
def(Score.class, Score::new))); def(Score.class, Score::new)));
private final Map<String, FunctionDefinition> defs = new LinkedHashMap<>(); private final Map<String, FunctionDefinition> defs = new LinkedHashMap<>();
@ -330,13 +332,17 @@ public class FunctionRegistry {
static <T extends Function> FunctionDefinition def(Class<T> function, static <T extends Function> FunctionDefinition def(Class<T> function,
BinaryFunctionBuilder<T> ctorRef, String... aliases) { BinaryFunctionBuilder<T> ctorRef, String... aliases) {
FunctionBuilder builder = (location, children, distinct, tz) -> { FunctionBuilder builder = (location, children, distinct, tz) -> {
if (children.size() != 2) { boolean isBinaryOptionalParamFunction = function.isAssignableFrom(Round.class) || function.isAssignableFrom(Truncate.class);
if (isBinaryOptionalParamFunction && (children.size() > 2 || children.size() < 1)) {
throw new IllegalArgumentException("expects one or two arguments");
} else if (!isBinaryOptionalParamFunction && children.size() != 2) {
throw new IllegalArgumentException("expects exactly two arguments"); throw new IllegalArgumentException("expects exactly two arguments");
} }
if (distinct) { if (distinct) {
throw new IllegalArgumentException("does not support DISTINCT yet it was specified"); throw new IllegalArgumentException("does not support DISTINCT yet it was specified");
} }
return ctorRef.build(location, children.get(0), children.get(1)); return ctorRef.build(location, children.get(0), children.size() == 2 ? children.get(1) : null);
}; };
return def(function, builder, false, aliases); return def(function, builder, false, aliases);
} }

View File

@ -7,6 +7,7 @@ package org.elasticsearch.xpack.sql.expression.function.scalar.math;
import org.elasticsearch.common.io.stream.StreamInput; import org.elasticsearch.common.io.stream.StreamInput;
import org.elasticsearch.common.io.stream.StreamOutput; import org.elasticsearch.common.io.stream.StreamOutput;
import org.elasticsearch.xpack.sql.SqlIllegalArgumentException;
import org.elasticsearch.xpack.sql.expression.function.scalar.math.BinaryMathProcessor.BinaryMathOperation; import org.elasticsearch.xpack.sql.expression.function.scalar.math.BinaryMathProcessor.BinaryMathOperation;
import org.elasticsearch.xpack.sql.expression.function.scalar.math.MathProcessor.MathOperation; import org.elasticsearch.xpack.sql.expression.function.scalar.math.MathProcessor.MathOperation;
import org.elasticsearch.xpack.sql.expression.function.scalar.processor.runtime.Processor; import org.elasticsearch.xpack.sql.expression.function.scalar.processor.runtime.Processor;
@ -22,7 +23,38 @@ public class BinaryMathProcessor extends BinaryNumericProcessor<BinaryMathOperat
public enum BinaryMathOperation implements BiFunction<Number, Number, Number> { public enum BinaryMathOperation implements BiFunction<Number, Number, Number> {
ATAN2((l, r) -> Math.atan2(l.doubleValue(), r.doubleValue())), ATAN2((l, r) -> Math.atan2(l.doubleValue(), r.doubleValue())),
POWER((l, r) -> Math.pow(l.doubleValue(), r.doubleValue())); POWER((l, r) -> Math.pow(l.doubleValue(), r.doubleValue())),
ROUND((l, r) -> {
if (l == null) {
return null;
}
if (r == null) {
return l;
}
if (r instanceof Float || r instanceof Double) {
throw new SqlIllegalArgumentException("An integer number is required; received [{}] as second parameter", r);
}
double tenAtScale = Math.pow(10., r.longValue());
double middleResult = l.doubleValue() * tenAtScale;
int sign = middleResult > 0 ? 1 : -1;
return Math.round(Math.abs(middleResult)) / tenAtScale * sign;
}),
TRUNCATE((l, r) -> {
if (l == null) {
return null;
}
if (r == null) {
return l;
}
if (r instanceof Float || r instanceof Double) {
throw new SqlIllegalArgumentException("An integer number is required; received [{}] as second parameter", r);
}
double tenAtScale = Math.pow(10., r.longValue());
double g = l.doubleValue() * tenAtScale;
return (((l.doubleValue() < 0) ? Math.ceil(g) : Math.floor(g)) / tenAtScale);
});
private final BiFunction<Number, Number, Number> process; private final BiFunction<Number, Number, Number> process;

View File

@ -52,7 +52,6 @@ public class MathProcessor implements Processor {
RANDOM((Object l) -> l != null ? RANDOM((Object l) -> l != null ?
new Random(((Number) l).longValue()).nextDouble() : new Random(((Number) l).longValue()).nextDouble() :
Randomness.get().nextDouble(), true), Randomness.get().nextDouble(), true),
ROUND((DoubleFunction<Object>) Math::round),
SIGN((DoubleFunction<Object>) Math::signum), SIGN((DoubleFunction<Object>) Math::signum),
SIN(Math::sin), SIN(Math::sin),
SINH(Math::sinh), SINH(Math::sinh),

View File

@ -6,41 +6,75 @@
package org.elasticsearch.xpack.sql.expression.function.scalar.math; package org.elasticsearch.xpack.sql.expression.function.scalar.math;
import org.elasticsearch.xpack.sql.expression.Expression; import org.elasticsearch.xpack.sql.expression.Expression;
import org.elasticsearch.xpack.sql.expression.function.scalar.math.MathProcessor.MathOperation; import org.elasticsearch.xpack.sql.expression.Literal;
import org.elasticsearch.xpack.sql.expression.function.scalar.math.BinaryMathProcessor.BinaryMathOperation;
import org.elasticsearch.xpack.sql.expression.function.scalar.processor.definition.ProcessorDefinition;
import org.elasticsearch.xpack.sql.expression.function.scalar.processor.definition.ProcessorDefinitions;
import org.elasticsearch.xpack.sql.expression.function.scalar.script.ScriptTemplate;
import org.elasticsearch.xpack.sql.tree.Location; import org.elasticsearch.xpack.sql.tree.Location;
import org.elasticsearch.xpack.sql.tree.NodeInfo; import org.elasticsearch.xpack.sql.tree.NodeInfo;
import org.elasticsearch.xpack.sql.type.DataType; import org.elasticsearch.xpack.sql.type.DataType;
import org.elasticsearch.xpack.sql.type.DataTypeConversion;
import java.util.Locale;
import java.util.function.BiFunction;
import static java.lang.String.format;
import static org.elasticsearch.xpack.sql.expression.function.scalar.script.ParamsBuilder.paramsBuilder;
/** /**
* <a href="https://en.wikipedia.org/wiki/Rounding#Round_half_up">Round</a> * Function that takes two parameters: one is the field/value itself, the other is a non-floating point numeric
* function. * which indicates how the rounding should behave. If positive, it will round the number till that parameter
* * count digits after the decimal point. If negative, it will round the number till that paramter count
* Note that this uses {@link Math#round(double)} which uses "half up" rounding * digits before the decimal point, starting at the decimal point.
* for `ROUND(-1.5)` rounds to `-1`.
*/ */
public class Round extends MathFunction { public class Round extends BinaryNumericFunction {
public Round(Location location, Expression field) {
super(location, field); public Round(Location location, Expression left, Expression right) {
super(location, left, right == null ? Literal.of(Location.EMPTY, 0) : right);
} }
@Override @Override
protected NodeInfo<Round> info() { protected NodeInfo<Round> info() {
return NodeInfo.create(this, Round::new, field()); return NodeInfo.create(this, Round::new, left(), right());
} }
@Override @Override
protected Round replaceChild(Expression newChild) { protected Round replaceChildren(Expression newLeft, Expression newRight) {
return new Round(location(), newChild); return new Round(location(), newLeft, newRight);
} }
@Override @Override
protected MathOperation operation() { protected BiFunction<Number, Number, Number> operation() {
return MathOperation.ROUND; return BinaryMathOperation.ROUND;
}
@Override
protected ProcessorDefinition makeProcessorDefinition() {
return new BinaryMathProcessorDefinition(location(), this,
ProcessorDefinitions.toProcessorDefinition(left()),
ProcessorDefinitions.toProcessorDefinition(right()),
BinaryMathOperation.ROUND);
}
protected TypeResolution resolveInputType(DataType inputType) {
return inputType.isNumeric() ?
TypeResolution.TYPE_RESOLVED :
new TypeResolution("'%s' requires a numeric type, received %s", mathFunction(), inputType.esType);
}
@Override
protected ScriptTemplate asScriptFrom(ScriptTemplate leftScript, ScriptTemplate rightScript) {
return new ScriptTemplate(format(Locale.ROOT, ScriptTemplate.formatTemplate("{sql}.%s(%s,%s)"),
mathFunction(),
leftScript.template(),
rightScript.template()),
paramsBuilder()
.script(leftScript.params()).script(rightScript.params())
.build(), dataType());
} }
@Override @Override
public DataType dataType() { public DataType dataType() {
return DataTypeConversion.asInteger(field().dataType()); return left().dataType();
} }
} }

View File

@ -0,0 +1,74 @@
/*
* Copyright Elasticsearch B.V. and/or licensed to Elasticsearch B.V. under one
* or more contributor license agreements. Licensed under the Elastic License;
* you may not use this file except in compliance with the Elastic License.
*/
package org.elasticsearch.xpack.sql.expression.function.scalar.math;
import org.elasticsearch.xpack.sql.expression.Expression;
import org.elasticsearch.xpack.sql.expression.Literal;
import org.elasticsearch.xpack.sql.expression.function.scalar.math.BinaryMathProcessor.BinaryMathOperation;
import org.elasticsearch.xpack.sql.expression.function.scalar.processor.definition.ProcessorDefinition;
import org.elasticsearch.xpack.sql.expression.function.scalar.processor.definition.ProcessorDefinitions;
import org.elasticsearch.xpack.sql.expression.function.scalar.script.ScriptTemplate;
import org.elasticsearch.xpack.sql.tree.Location;
import org.elasticsearch.xpack.sql.tree.NodeInfo;
import org.elasticsearch.xpack.sql.type.DataType;
import java.util.Locale;
import java.util.function.BiFunction;
import static java.lang.String.format;
import static org.elasticsearch.xpack.sql.expression.function.scalar.script.ParamsBuilder.paramsBuilder;
/**
* Function that takes two parameters: one is the field/value itself, the other is a non-floating point numeric
* which indicates how the truncation should behave. If positive, it will truncate the number till that
* parameter count digits after the decimal point. If negative, it will truncate the number till that parameter
* count digits before the decimal point, starting at the decimal point.
*/
public class Truncate extends BinaryNumericFunction {
public Truncate(Location location, Expression left, Expression right) {
super(location, left, right == null ? Literal.of(Location.EMPTY, 0) : right);
}
@Override
protected NodeInfo<Truncate> info() {
return NodeInfo.create(this, Truncate::new, left(), right());
}
@Override
protected Truncate replaceChildren(Expression newLeft, Expression newRight) {
return new Truncate(location(), newLeft, newRight);
}
@Override
protected BiFunction<Number, Number, Number> operation() {
return BinaryMathOperation.TRUNCATE;
}
@Override
protected ProcessorDefinition makeProcessorDefinition() {
return new BinaryMathProcessorDefinition(location(), this,
ProcessorDefinitions.toProcessorDefinition(left()),
ProcessorDefinitions.toProcessorDefinition(right()),
BinaryMathOperation.TRUNCATE);
}
@Override
protected ScriptTemplate asScriptFrom(ScriptTemplate leftScript, ScriptTemplate rightScript) {
return new ScriptTemplate(format(Locale.ROOT, ScriptTemplate.formatTemplate("{sql}.%s(%s,%s)"),
mathFunction(),
leftScript.template(),
rightScript.template()),
paramsBuilder()
.script(leftScript.params()).script(rightScript.params())
.build(), dataType());
}
@Override
public DataType dataType() {
return left().dataType();
}
}

View File

@ -8,6 +8,7 @@ package org.elasticsearch.xpack.sql.expression.function.scalar.whitelist;
import org.elasticsearch.xpack.sql.expression.function.scalar.datetime.DateTimeFunction; import org.elasticsearch.xpack.sql.expression.function.scalar.datetime.DateTimeFunction;
import org.elasticsearch.xpack.sql.expression.function.scalar.datetime.NamedDateTimeProcessor.NameExtractor; import org.elasticsearch.xpack.sql.expression.function.scalar.datetime.NamedDateTimeProcessor.NameExtractor;
import org.elasticsearch.xpack.sql.expression.function.scalar.datetime.QuarterProcessor; import org.elasticsearch.xpack.sql.expression.function.scalar.datetime.QuarterProcessor;
import org.elasticsearch.xpack.sql.expression.function.scalar.math.BinaryMathProcessor.BinaryMathOperation;
import org.elasticsearch.xpack.sql.expression.function.scalar.string.BinaryStringNumericProcessor.BinaryStringNumericOperation; import org.elasticsearch.xpack.sql.expression.function.scalar.string.BinaryStringNumericProcessor.BinaryStringNumericOperation;
import org.elasticsearch.xpack.sql.expression.function.scalar.string.BinaryStringStringProcessor.BinaryStringStringOperation; import org.elasticsearch.xpack.sql.expression.function.scalar.string.BinaryStringStringProcessor.BinaryStringStringOperation;
import org.elasticsearch.xpack.sql.expression.function.scalar.string.ConcatFunctionProcessor; import org.elasticsearch.xpack.sql.expression.function.scalar.string.ConcatFunctionProcessor;
@ -121,4 +122,12 @@ public final class InternalSqlScriptUtils {
public static Integer locate(String s1, String s2) { public static Integer locate(String s1, String s2) {
return locate(s1, s2, null); return locate(s1, s2, null);
} }
public static Number round(Number v, Number s) {
return BinaryMathOperation.ROUND.apply(v, s);
}
public static Number truncate(Number v, Number s) {
return BinaryMathOperation.TRUNCATE.apply(v, s);
}
} }

View File

@ -8,6 +8,7 @@ package org.elasticsearch.xpack.sql.plugin;
import org.elasticsearch.painless.spi.PainlessExtension; import org.elasticsearch.painless.spi.PainlessExtension;
import org.elasticsearch.painless.spi.Whitelist; import org.elasticsearch.painless.spi.Whitelist;
import org.elasticsearch.painless.spi.WhitelistLoader; import org.elasticsearch.painless.spi.WhitelistLoader;
import org.elasticsearch.script.BucketAggregationSelectorScript;
import org.elasticsearch.script.FilterScript; import org.elasticsearch.script.FilterScript;
import org.elasticsearch.script.ScriptContext; import org.elasticsearch.script.ScriptContext;
import org.elasticsearch.script.SearchScript; import org.elasticsearch.script.SearchScript;
@ -30,6 +31,7 @@ public class SqlPainlessExtension implements PainlessExtension {
whitelist.put(SearchScript.AGGS_CONTEXT, list); whitelist.put(SearchScript.AGGS_CONTEXT, list);
whitelist.put(SearchScript.CONTEXT, list); whitelist.put(SearchScript.CONTEXT, list);
whitelist.put(SearchScript.SCRIPT_SORT_CONTEXT, list); whitelist.put(SearchScript.SCRIPT_SORT_CONTEXT, list);
whitelist.put(BucketAggregationSelectorScript.CONTEXT, list);
return whitelist; return whitelist;
} }
} }

View File

@ -12,24 +12,26 @@ class org.elasticsearch.xpack.sql.expression.function.scalar.whitelist.InternalS
String dayName(long, String) String dayName(long, String)
String monthName(long, String) String monthName(long, String)
Integer quarter(long, String) Integer quarter(long, String)
Number round(Number, Number)
Number truncate(Number, Number)
Integer ascii(String) Integer ascii(String)
Integer bitLength(String) Integer bitLength(String)
String character(Number)
Integer charLength(String) Integer charLength(String)
String lcase(String) String character(Number)
String ucase(String)
Integer length(String)
String rtrim(String)
String ltrim(String)
String space(Number)
String left(String, int)
String right(String, int)
String concat(String, String) String concat(String, String)
String repeat(String, int)
Integer position(String, String)
String insert(String, int, int, String) String insert(String, int, int, String)
String substring(String, int, int) String lcase(String)
String replace(String, String, String) String left(String, int)
Integer length(String)
Integer locate(String, String) Integer locate(String, String)
Integer locate(String, String, Integer) Integer locate(String, String, Integer)
String ltrim(String)
Integer position(String, String)
String repeat(String, int)
String replace(String, String, String)
String right(String, int)
String rtrim(String)
String space(Number)
String substring(String, int, int)
String ucase(String)
} }

View File

@ -8,6 +8,7 @@ package org.elasticsearch.xpack.sql.expression.function.scalar.math;
import org.elasticsearch.common.io.stream.NamedWriteableRegistry; import org.elasticsearch.common.io.stream.NamedWriteableRegistry;
import org.elasticsearch.common.io.stream.Writeable.Reader; import org.elasticsearch.common.io.stream.Writeable.Reader;
import org.elasticsearch.test.AbstractWireSerializingTestCase; import org.elasticsearch.test.AbstractWireSerializingTestCase;
import org.elasticsearch.xpack.sql.SqlIllegalArgumentException;
import org.elasticsearch.xpack.sql.expression.Literal; import org.elasticsearch.xpack.sql.expression.Literal;
import org.elasticsearch.xpack.sql.expression.function.scalar.Processors; import org.elasticsearch.xpack.sql.expression.function.scalar.Processors;
import org.elasticsearch.xpack.sql.expression.function.scalar.processor.runtime.ConstantProcessor; import org.elasticsearch.xpack.sql.expression.function.scalar.processor.runtime.ConstantProcessor;
@ -48,6 +49,69 @@ public class BinaryMathProcessorTests extends AbstractWireSerializingTestCase<Bi
assertEquals(4d, ba.process(null)); assertEquals(4d, ba.process(null));
} }
public void testRoundWithValidInput() {
assertEquals(123.0, new Round(EMPTY, l(123), l(3)).makeProcessorDefinition().asProcessor().process(null));
assertEquals(123.5, new Round(EMPTY, l(123.45), l(1)).makeProcessorDefinition().asProcessor().process(null));
assertEquals(123.0, new Round(EMPTY, l(123.45), l(0)).makeProcessorDefinition().asProcessor().process(null));
assertEquals(123.0, new Round(EMPTY, l(123.45), null).makeProcessorDefinition().asProcessor().process(null));
assertEquals(-100.0, new Round(EMPTY, l(-123), l(-2)).makeProcessorDefinition().asProcessor().process(null));
assertEquals(-120.0, new Round(EMPTY, l(-123.45), l(-1)).makeProcessorDefinition().asProcessor().process(null));
assertEquals(-124.0, new Round(EMPTY, l(-123.5), l(0)).makeProcessorDefinition().asProcessor().process(null));
assertEquals(-123.0, new Round(EMPTY, l(-123.45), null).makeProcessorDefinition().asProcessor().process(null));
}
public void testRoundFunctionWithEdgeCasesInputs() {
assertNull(new Round(EMPTY, l(null), l(3)).makeProcessorDefinition().asProcessor().process(null));
assertEquals(-0.0, new Round(EMPTY, l(0), l(0)).makeProcessorDefinition().asProcessor().process(null));
assertEquals((double) Long.MAX_VALUE, new Round(EMPTY, l(Long.MAX_VALUE), l(0))
.makeProcessorDefinition().asProcessor().process(null));
assertEquals(0.0, new Round(EMPTY, l(123.456), l(Integer.MAX_VALUE)).makeProcessorDefinition().asProcessor().process(null));
}
public void testRoundInputValidation() {
SqlIllegalArgumentException siae = expectThrows(SqlIllegalArgumentException.class,
() -> new Round(EMPTY, l(5), l("foobarbar")).makeProcessorDefinition().asProcessor().process(null));
assertEquals("A number is required; received foobarbar", siae.getMessage());
siae = expectThrows(SqlIllegalArgumentException.class,
() -> new Round(EMPTY, l("bla"), l(0)).makeProcessorDefinition().asProcessor().process(null));
assertEquals("A number is required; received bla", siae.getMessage());
siae = expectThrows(SqlIllegalArgumentException.class,
() -> new Round(EMPTY, l(123.34), l(0.1)).makeProcessorDefinition().asProcessor().process(null));
assertEquals("An integer number is required; received [0.1] as second parameter", siae.getMessage());
}
public void testTruncateWithValidInput() {
assertEquals(123.0, new Truncate(EMPTY, l(123), l(3)).makeProcessorDefinition().asProcessor().process(null));
assertEquals(123.4, new Truncate(EMPTY, l(123.45), l(1)).makeProcessorDefinition().asProcessor().process(null));
assertEquals(123.0, new Truncate(EMPTY, l(123.45), l(0)).makeProcessorDefinition().asProcessor().process(null));
assertEquals(123.0, new Truncate(EMPTY, l(123.45), null).makeProcessorDefinition().asProcessor().process(null));
assertEquals(-100.0, new Truncate(EMPTY, l(-123), l(-2)).makeProcessorDefinition().asProcessor().process(null));
assertEquals(-120.0, new Truncate(EMPTY, l(-123.45), l(-1)).makeProcessorDefinition().asProcessor().process(null));
assertEquals(-123.0, new Truncate(EMPTY, l(-123.5), l(0)).makeProcessorDefinition().asProcessor().process(null));
assertEquals(-123.0, new Truncate(EMPTY, l(-123.45), null).makeProcessorDefinition().asProcessor().process(null));
}
public void testTruncateFunctionWithEdgeCasesInputs() {
assertNull(new Truncate(EMPTY, l(null), l(3)).makeProcessorDefinition().asProcessor().process(null));
assertEquals(0.0, new Truncate(EMPTY, l(0), l(0)).makeProcessorDefinition().asProcessor().process(null));
assertEquals((double) Long.MAX_VALUE, new Truncate(EMPTY, l(Long.MAX_VALUE), l(0))
.makeProcessorDefinition().asProcessor().process(null));
assertEquals(Double.NaN, new Truncate(EMPTY, l(123.456), l(Integer.MAX_VALUE))
.makeProcessorDefinition().asProcessor().process(null));
}
public void testTruncateInputValidation() {
SqlIllegalArgumentException siae = expectThrows(SqlIllegalArgumentException.class,
() -> new Truncate(EMPTY, l(5), l("foobarbar")).makeProcessorDefinition().asProcessor().process(null));
assertEquals("A number is required; received foobarbar", siae.getMessage());
siae = expectThrows(SqlIllegalArgumentException.class,
() -> new Truncate(EMPTY, l("bla"), l(0)).makeProcessorDefinition().asProcessor().process(null));
assertEquals("A number is required; received bla", siae.getMessage());
siae = expectThrows(SqlIllegalArgumentException.class,
() -> new Truncate(EMPTY, l(123.34), l(0.1)).makeProcessorDefinition().asProcessor().process(null));
assertEquals("An integer number is required; received [0.1] as second parameter", siae.getMessage());
}
public void testHandleNull() { public void testHandleNull() {
assertNull(new ATan2(EMPTY, l(null), l(3)).makeProcessorDefinition().asProcessor().process(null)); assertNull(new ATan2(EMPTY, l(null), l(3)).makeProcessorDefinition().asProcessor().process(null));
assertNull(new Power(EMPTY, l(null), l(null)).makeProcessorDefinition().asProcessor().process(null)); assertNull(new Power(EMPTY, l(null), l(null)).makeProcessorDefinition().asProcessor().process(null));

View File

@ -49,16 +49,18 @@ public abstract class ShowTestCase extends CliIntegrationTestCase {
assertThat(readLine(), RegexMatcher.matches("\\s*LOG\\s*\\|\\s*SCALAR\\s*")); assertThat(readLine(), RegexMatcher.matches("\\s*LOG\\s*\\|\\s*SCALAR\\s*"));
assertThat(readLine(), RegexMatcher.matches("\\s*LOG10\\s*\\|\\s*SCALAR\\s*")); assertThat(readLine(), RegexMatcher.matches("\\s*LOG10\\s*\\|\\s*SCALAR\\s*"));
assertThat(readLine(), RegexMatcher.matches("\\s*LCASE\\s*\\|\\s*SCALAR\\s*")); assertThat(readLine(), RegexMatcher.matches("\\s*LCASE\\s*\\|\\s*SCALAR\\s*"));
assertThat(readLine(), RegexMatcher.matches("\\s*LENGTH\\s*\\|\\s*SCALAR\\s*"));
assertThat(readLine(), RegexMatcher.matches("\\s*LTRIM\\s*\\|\\s*SCALAR\\s*"));
assertThat(readLine(), RegexMatcher.matches("\\s*LEFT\\s*\\|\\s*SCALAR\\s*")); assertThat(readLine(), RegexMatcher.matches("\\s*LEFT\\s*\\|\\s*SCALAR\\s*"));
assertThat(readLine(), RegexMatcher.matches("\\s*LENGTH\\s*\\|\\s*SCALAR\\s*"));
assertThat(readLine(), RegexMatcher.matches("\\s*LOCATE\\s*\\|\\s*SCALAR\\s*")); assertThat(readLine(), RegexMatcher.matches("\\s*LOCATE\\s*\\|\\s*SCALAR\\s*"));
assertThat(readLine(), RegexMatcher.matches("\\s*LTRIM\\s*\\|\\s*SCALAR\\s*"));
assertEquals("", readLine()); assertEquals("", readLine());
} }
public void testShowFunctionsLikeInfix() throws IOException { public void testShowFunctionsLikeInfix() throws IOException {
assertThat(command("SHOW FUNCTIONS LIKE '%DAY%'"), RegexMatcher.matches("\\s*name\\s*\\|\\s*type\\s*")); assertThat(command("SHOW FUNCTIONS LIKE '%DAY%'"), RegexMatcher.matches("\\s*name\\s*\\|\\s*type\\s*"));
assertThat(readLine(), containsString("----------")); assertThat(readLine(), containsString("----------"));
assertThat(readLine(), RegexMatcher.matches("\\s*DAY_NAME\\s*\\|\\s*SCALAR\\s*"));
assertThat(readLine(), RegexMatcher.matches("\\s*DAYNAME\\s*\\|\\s*SCALAR\\s*"));
assertThat(readLine(), RegexMatcher.matches("\\s*DAY_OF_MONTH\\s*\\|\\s*SCALAR\\s*")); assertThat(readLine(), RegexMatcher.matches("\\s*DAY_OF_MONTH\\s*\\|\\s*SCALAR\\s*"));
assertThat(readLine(), RegexMatcher.matches("\\s*DAYOFMONTH\\s*\\|\\s*SCALAR\\s*")); assertThat(readLine(), RegexMatcher.matches("\\s*DAYOFMONTH\\s*\\|\\s*SCALAR\\s*"));
assertThat(readLine(), RegexMatcher.matches("\\s*DAY\\s*\\|\\s*SCALAR\\s*")); assertThat(readLine(), RegexMatcher.matches("\\s*DAY\\s*\\|\\s*SCALAR\\s*"));
@ -68,8 +70,6 @@ public abstract class ShowTestCase extends CliIntegrationTestCase {
assertThat(readLine(), RegexMatcher.matches("\\s*DAYOFYEAR\\s*\\|\\s*SCALAR\\s*")); assertThat(readLine(), RegexMatcher.matches("\\s*DAYOFYEAR\\s*\\|\\s*SCALAR\\s*"));
assertThat(readLine(), RegexMatcher.matches("\\s*HOUR_OF_DAY\\s*\\|\\s*SCALAR\\s*")); assertThat(readLine(), RegexMatcher.matches("\\s*HOUR_OF_DAY\\s*\\|\\s*SCALAR\\s*"));
assertThat(readLine(), RegexMatcher.matches("\\s*MINUTE_OF_DAY\\s*\\|\\s*SCALAR\\s*")); assertThat(readLine(), RegexMatcher.matches("\\s*MINUTE_OF_DAY\\s*\\|\\s*SCALAR\\s*"));
assertThat(readLine(), RegexMatcher.matches("\\s*DAY_NAME\\s*\\|\\s*SCALAR\\s*"));
assertThat(readLine(), RegexMatcher.matches("\\s*DAYNAME\\s*\\|\\s*SCALAR\\s*"));
assertEquals("", readLine()); assertEquals("", readLine());
} }
} }

View File

@ -38,6 +38,7 @@ public abstract class CsvSpecTestCase extends SpecBaseIntegrationTestCase {
tests.addAll(readScriptSpec("/nulls.csv-spec", parser)); tests.addAll(readScriptSpec("/nulls.csv-spec", parser));
tests.addAll(readScriptSpec("/nested.csv-spec", parser)); tests.addAll(readScriptSpec("/nested.csv-spec", parser));
tests.addAll(readScriptSpec("/functions.csv-spec", parser)); tests.addAll(readScriptSpec("/functions.csv-spec", parser));
tests.addAll(readScriptSpec("/math.csv-spec", parser));
return tests; return tests;
} }

View File

@ -370,7 +370,7 @@ SELECT MIN(salary) mi, MAX(salary) ma, MAX(salary) - MIN(salary) AS d FROM test_
aggHavingWithMultipleScalarFunctionsBasedOnAliasFromGroupBy aggHavingWithMultipleScalarFunctionsBasedOnAliasFromGroupBy
SELECT MIN(salary) mi, MAX(salary) ma, MAX(salary) - MIN(salary) AS d FROM test_emp GROUP BY languages HAVING d - ma % mi > 0 AND AVG(salary) > 30000 ORDER BY languages; SELECT MIN(salary) mi, MAX(salary) ma, MAX(salary) - MIN(salary) AS d FROM test_emp GROUP BY languages HAVING d - ma % mi > 0 AND AVG(salary) > 30000 ORDER BY languages;
aggHavingWithMultipleScalarFunctionsBasedOnAliasFromGroupByAndAggNotInGroupBy aggHavingWithMultipleScalarFunctionsBasedOnAliasFromGroupByAndAggNotInGroupBy
SELECT MIN(salary) mi, MAX(salary) ma, MAX(salary) - MIN(salary) AS d FROM test_emp GROUP BY languages HAVING ROUND(d - ABS(ma % mi)) + AVG(salary) > 0 AND AVG(salary) > 30000 ORDER BY languages; SELECT MIN(salary) mi, MAX(salary) ma, MAX(salary) - MIN(salary) AS d FROM test_emp GROUP BY languages HAVING ROUND((d - ABS(ma % mi))) + AVG(salary) > 0 AND AVG(salary) > 30000 ORDER BY languages;
aggHavingScalarOnAggFunctionsWithoutAliasesInAndNotInGroupBy aggHavingScalarOnAggFunctionsWithoutAliasesInAndNotInGroupBy
SELECT MIN(salary) mi, MAX(salary) ma, MAX(salary) - MIN(salary) AS d FROM test_emp GROUP BY languages HAVING MAX(salary) % MIN(salary) + AVG(salary) > 3000 ORDER BY languages; SELECT MIN(salary) mi, MAX(salary) ma, MAX(salary) - MIN(salary) AS d FROM test_emp GROUP BY languages HAVING MAX(salary) % MIN(salary) + AVG(salary) > 3000 ORDER BY languages;
@ -385,7 +385,7 @@ SELECT MIN(salary) mi, MAX(salary) ma, MAX(salary) - MIN(salary) AS d FROM test_
aggMultiGroupByHavingWithMultipleScalarFunctionsBasedOnAliasFromGroupBy aggMultiGroupByHavingWithMultipleScalarFunctionsBasedOnAliasFromGroupBy
SELECT MIN(salary) mi, MAX(salary) ma, MAX(salary) - MIN(salary) AS d FROM test_emp GROUP BY gender, languages HAVING d - ma % mi > 0 AND AVG(salary) > 30000 ORDER BY gender, languages; SELECT MIN(salary) mi, MAX(salary) ma, MAX(salary) - MIN(salary) AS d FROM test_emp GROUP BY gender, languages HAVING d - ma % mi > 0 AND AVG(salary) > 30000 ORDER BY gender, languages;
aggMultiGroupByHavingWithMultipleScalarFunctionsBasedOnAliasFromGroupByAndAggNotInGroupBy aggMultiGroupByHavingWithMultipleScalarFunctionsBasedOnAliasFromGroupByAndAggNotInGroupBy
SELECT MIN(salary) mi, MAX(salary) ma, MAX(salary) - MIN(salary) AS d FROM test_emp GROUP BY gender, languages HAVING ROUND(d - ABS(ma % mi)) + AVG(salary) > 0 AND AVG(salary) > 30000 ORDER BY gender, languages; SELECT MIN(salary) mi, MAX(salary) ma, MAX(salary) - MIN(salary) AS d FROM test_emp GROUP BY gender, languages HAVING ROUND((d - ABS(ma % mi))) + AVG(salary) > 0 AND AVG(salary) > 30000 ORDER BY gender, languages;
aggMultiGroupByHavingScalarOnAggFunctionsWithoutAliasesInAndNotInGroupBy aggMultiGroupByHavingScalarOnAggFunctionsWithoutAliasesInAndNotInGroupBy
SELECT MIN(salary) mi, MAX(salary) ma, MAX(salary) - MIN(salary) AS d FROM test_emp GROUP BY gender, languages HAVING MAX(salary) % MIN(salary) + AVG(salary) > 3000 ORDER BY gender, languages; SELECT MIN(salary) mi, MAX(salary) ma, MAX(salary) - MIN(salary) AS d FROM test_emp GROUP BY gender, languages HAVING MAX(salary) % MIN(salary) + AVG(salary) > 3000 ORDER BY gender, languages;

View File

@ -19,6 +19,8 @@ PERCENTILE_RANK |AGGREGATE
SUM_OF_SQUARES |AGGREGATE SUM_OF_SQUARES |AGGREGATE
SKEWNESS |AGGREGATE SKEWNESS |AGGREGATE
KURTOSIS |AGGREGATE KURTOSIS |AGGREGATE
DAY_NAME |SCALAR
DAYNAME |SCALAR
DAY_OF_MONTH |SCALAR DAY_OF_MONTH |SCALAR
DAYOFMONTH |SCALAR DAYOFMONTH |SCALAR
DAY |SCALAR DAY |SCALAR
@ -34,18 +36,16 @@ HOUR |SCALAR
MINUTE_OF_DAY |SCALAR MINUTE_OF_DAY |SCALAR
MINUTE_OF_HOUR |SCALAR MINUTE_OF_HOUR |SCALAR
MINUTE |SCALAR MINUTE |SCALAR
SECOND_OF_MINUTE|SCALAR MONTH_NAME |SCALAR
SECOND |SCALAR MONTHNAME |SCALAR
MONTH_OF_YEAR |SCALAR MONTH_OF_YEAR |SCALAR
MONTH |SCALAR MONTH |SCALAR
SECOND_OF_MINUTE|SCALAR
SECOND |SCALAR
QUARTER |SCALAR
YEAR |SCALAR YEAR |SCALAR
WEEK_OF_YEAR |SCALAR WEEK_OF_YEAR |SCALAR
WEEK |SCALAR WEEK |SCALAR
DAY_NAME |SCALAR
DAYNAME |SCALAR
MONTH_NAME |SCALAR
MONTHNAME |SCALAR
QUARTER |SCALAR
ABS |SCALAR ABS |SCALAR
ACOS |SCALAR ACOS |SCALAR
ASIN |SCALAR ASIN |SCALAR
@ -77,24 +77,25 @@ SIN |SCALAR
SINH |SCALAR SINH |SCALAR
SQRT |SCALAR SQRT |SCALAR
TAN |SCALAR TAN |SCALAR
TRUNCATE |SCALAR
ASCII |SCALAR ASCII |SCALAR
CHAR |SCALAR
BIT_LENGTH |SCALAR BIT_LENGTH |SCALAR
CHAR |SCALAR
CHAR_LENGTH |SCALAR CHAR_LENGTH |SCALAR
CHARACTER_LENGTH|SCALAR CHARACTER_LENGTH|SCALAR
LCASE |SCALAR
LENGTH |SCALAR
LTRIM |SCALAR
RTRIM |SCALAR
SPACE |SCALAR
CONCAT |SCALAR CONCAT |SCALAR
INSERT |SCALAR INSERT |SCALAR
LCASE |SCALAR
LEFT |SCALAR LEFT |SCALAR
LENGTH |SCALAR
LOCATE |SCALAR LOCATE |SCALAR
LTRIM |SCALAR
POSITION |SCALAR POSITION |SCALAR
REPEAT |SCALAR REPEAT |SCALAR
REPLACE |SCALAR REPLACE |SCALAR
RIGHT |SCALAR RIGHT |SCALAR
RTRIM |SCALAR
SPACE |SCALAR
SUBSTRING |SCALAR SUBSTRING |SCALAR
UCASE |SCALAR UCASE |SCALAR
SCORE |SCORE SCORE |SCORE
@ -133,6 +134,8 @@ showFunctionsWithLeadingPattern
SHOW FUNCTIONS LIKE '%DAY%'; SHOW FUNCTIONS LIKE '%DAY%';
name:s | type:s name:s | type:s
DAY_NAME |SCALAR
DAYNAME |SCALAR
DAY_OF_MONTH |SCALAR DAY_OF_MONTH |SCALAR
DAYOFMONTH |SCALAR DAYOFMONTH |SCALAR
DAY |SCALAR DAY |SCALAR
@ -142,8 +145,6 @@ DAY_OF_YEAR |SCALAR
DAYOFYEAR |SCALAR DAYOFYEAR |SCALAR
HOUR_OF_DAY |SCALAR HOUR_OF_DAY |SCALAR
MINUTE_OF_DAY |SCALAR MINUTE_OF_DAY |SCALAR
DAY_NAME |SCALAR
DAYNAME |SCALAR
; ;
showTables showTables

View File

@ -195,6 +195,8 @@ PERCENTILE_RANK |AGGREGATE
SUM_OF_SQUARES |AGGREGATE SUM_OF_SQUARES |AGGREGATE
SKEWNESS |AGGREGATE SKEWNESS |AGGREGATE
KURTOSIS |AGGREGATE KURTOSIS |AGGREGATE
DAY_NAME |SCALAR
DAYNAME |SCALAR
DAY_OF_MONTH |SCALAR DAY_OF_MONTH |SCALAR
DAYOFMONTH |SCALAR DAYOFMONTH |SCALAR
DAY |SCALAR DAY |SCALAR
@ -210,18 +212,16 @@ HOUR |SCALAR
MINUTE_OF_DAY |SCALAR MINUTE_OF_DAY |SCALAR
MINUTE_OF_HOUR |SCALAR MINUTE_OF_HOUR |SCALAR
MINUTE |SCALAR MINUTE |SCALAR
SECOND_OF_MINUTE|SCALAR MONTH_NAME |SCALAR
SECOND |SCALAR MONTHNAME |SCALAR
MONTH_OF_YEAR |SCALAR MONTH_OF_YEAR |SCALAR
MONTH |SCALAR MONTH |SCALAR
SECOND_OF_MINUTE|SCALAR
SECOND |SCALAR
QUARTER |SCALAR
YEAR |SCALAR YEAR |SCALAR
WEEK_OF_YEAR |SCALAR WEEK_OF_YEAR |SCALAR
WEEK |SCALAR WEEK |SCALAR
DAY_NAME |SCALAR
DAYNAME |SCALAR
MONTH_NAME |SCALAR
MONTHNAME |SCALAR
QUARTER |SCALAR
ABS |SCALAR ABS |SCALAR
ACOS |SCALAR ACOS |SCALAR
ASIN |SCALAR ASIN |SCALAR
@ -253,24 +253,25 @@ SIN |SCALAR
SINH |SCALAR SINH |SCALAR
SQRT |SCALAR SQRT |SCALAR
TAN |SCALAR TAN |SCALAR
TRUNCATE |SCALAR
ASCII |SCALAR ASCII |SCALAR
CHAR |SCALAR
BIT_LENGTH |SCALAR BIT_LENGTH |SCALAR
CHAR |SCALAR
CHAR_LENGTH |SCALAR CHAR_LENGTH |SCALAR
CHARACTER_LENGTH|SCALAR CHARACTER_LENGTH|SCALAR
LCASE |SCALAR
LENGTH |SCALAR
LTRIM |SCALAR
RTRIM |SCALAR
SPACE |SCALAR
CONCAT |SCALAR CONCAT |SCALAR
INSERT |SCALAR INSERT |SCALAR
LCASE |SCALAR
LEFT |SCALAR LEFT |SCALAR
LENGTH |SCALAR
LOCATE |SCALAR LOCATE |SCALAR
LTRIM |SCALAR
POSITION |SCALAR POSITION |SCALAR
REPEAT |SCALAR REPEAT |SCALAR
REPLACE |SCALAR REPLACE |SCALAR
RIGHT |SCALAR RIGHT |SCALAR
RTRIM |SCALAR
SPACE |SCALAR
SUBSTRING |SCALAR SUBSTRING |SCALAR
UCASE |SCALAR UCASE |SCALAR
SCORE |SCORE SCORE |SCORE
@ -321,6 +322,8 @@ SHOW FUNCTIONS LIKE '%DAY%';
name | type name | type
---------------+--------------- ---------------+---------------
DAY_NAME |SCALAR
DAYNAME |SCALAR
DAY_OF_MONTH |SCALAR DAY_OF_MONTH |SCALAR
DAYOFMONTH |SCALAR DAYOFMONTH |SCALAR
DAY |SCALAR DAY |SCALAR
@ -330,8 +333,6 @@ DAY_OF_YEAR |SCALAR
DAYOFYEAR |SCALAR DAYOFYEAR |SCALAR
HOUR_OF_DAY |SCALAR HOUR_OF_DAY |SCALAR
MINUTE_OF_DAY |SCALAR MINUTE_OF_DAY |SCALAR
DAY_NAME |SCALAR
DAYNAME |SCALAR
// end::showFunctionsWithPattern // end::showFunctionsWithPattern
; ;
@ -548,7 +549,7 @@ M |63
groupByAndAggExpression groupByAndAggExpression
// tag::groupByAndAggExpression // tag::groupByAndAggExpression
SELECT gender AS g, ROUND(MIN(salary) / 100) AS salary FROM emp GROUP BY gender; SELECT gender AS g, ROUND((MIN(salary) / 100)) AS salary FROM emp GROUP BY gender;
g | salary g | salary
---------------+--------------- ---------------+---------------
@ -1124,3 +1125,43 @@ SELECT YEAR(CAST('2018-05-19T11:23:45Z' AS TIMESTAMP)) AS year;
2018 2018
// end::conversionStringToDateCast // end::conversionStringToDateCast
; ;
mathRoundWithNegativeParameter
// tag::mathRoundWithNegativeParameter
SELECT ROUND(-345.153, -1) AS rounded;
rounded
---------------
-350.0
// end::mathRoundWithNegativeParameter
;
mathRoundWithPositiveParameter
// tag::mathRoundWithPositiveParameter
SELECT ROUND(-345.153, 1) AS rounded;
rounded
---------------
-345.2
// end::mathRoundWithPositiveParameter
;
mathTruncateWithNegativeParameter
// tag::mathTruncateWithNegativeParameter
SELECT TRUNCATE(-345.153, -1) AS trimmed;
trimmed
---------------
-340.0
// end::mathTruncateWithNegativeParameter
;
mathTruncateWithPositiveParameter
// tag::mathTruncateWithPositiveParameter
SELECT TRUNCATE(-345.153, 1) AS trimmed;
trimmed
---------------
-345.1
// end::mathTruncateWithPositiveParameter
;

View File

@ -0,0 +1,185 @@
// this one doesn't work in H2 at all
truncateWithAsciiHavingAndOrderBy
SELECT TRUNCATE(ASCII(LEFT(first_name, 1)), 1), COUNT(*) count FROM test_emp GROUP BY ASCII(LEFT(first_name, 1)) HAVING COUNT(*) > 5 ORDER BY TRUNCATE(ASCII(LEFT(first_name, 1)), 1) DESC;
TRUNCATE(ASCII(LEFT(first_name,1)),1):i| count:l
---------------------------------------+---------------
65 |9
66 |8
72 |7
75 |8
77 |9
80 |6
83 |11
;
truncateWithNoSecondParameterWithAsciiHavingAndOrderBy
SELECT TRUNCATE(ASCII(LEFT(first_name, 1))), COUNT(*) count FROM test_emp GROUP BY ASCII(LEFT(first_name, 1)) HAVING COUNT(*) > 5 ORDER BY TRUNCATE(ASCII(LEFT(first_name, 1))) DESC;
TRUNCATE(ASCII(LEFT(first_name,1)),0):i| count:l
---------------------------------------+---------------
65 |9
66 |8
72 |7
75 |8
77 |9
80 |6
83 |11
;
roundWithGroupByAndOrderBy
SELECT ROUND(salary, 2) ROUNDED, salary FROM test_emp GROUP BY ROUNDED, salary ORDER BY ROUNDED LIMIT 10;
ROUNDED | salary
-------------+---------------
25324 |25324
25945 |25945
25976 |25976
26436 |26436
27215 |27215
28035 |28035
28336 |28336
28941 |28941
29175 |29175
30404 |30404
;
truncateWithGroupByAndOrderBy
SELECT TRUNCATE(salary, 2) TRUNCATED, salary FROM test_emp GROUP BY TRUNCATED, salary ORDER BY TRUNCATED LIMIT 10;
TRUNCATED | salary
-------------+---------------
25324 |25324
25945 |25945
25976 |25976
26436 |26436
27215 |27215
28035 |28035
28336 |28336
28941 |28941
29175 |29175
30404 |30404
;
truncateWithAsciiAndOrderBy
SELECT TRUNCATE(ASCII(LEFT(first_name,1)), -1) AS initial, first_name, ASCII(LEFT(first_name, 1)) FROM test_emp ORDER BY ASCII(LEFT(first_name, 1)) DESC LIMIT 15;
initial | first_name |ASCII(LEFT(first_name,1))
---------------+---------------+-------------------------
90 |Zvonko |90
90 |Zhongwei |90
80 |Yongqiao |89
80 |Yishay |89
80 |Yinghua |89
80 |Xinglin |88
80 |Weiyi |87
80 |Vishv |86
80 |Valdiodio |86
80 |Valter |86
80 |Uri |85
80 |Udi |85
80 |Tzvetan |84
80 |Tse |84
80 |Tuval |84
;
truncateWithHavingAndGroupBy
SELECT MIN(salary) mi, MAX(salary) ma, COUNT(*) c, TRUNCATE(AVG(salary)) tr FROM test_emp GROUP BY languages HAVING TRUNCATE(AVG(salary)) > 40000 ORDER BY languages;
mi:i | ma:I | c:l | tr:i
---------------+---------------+-----------------+-----------------
25976 |73717 |16 |49875
29175 |73578 |20 |48164
26436 |74999 |22 |52154
27215 |74572 |18 |47733
25324 |73851 |24 |44040
;
// https://github.com/elastic/elasticsearch/issues/33773
minMaxTruncateAndRoundOfAverageWithHavingRoundAndTruncate-Ignore
SELECT MIN(salary) mi, MAX(salary) ma, YEAR(hire_date) year, ROUND(AVG(languages), 1), TRUNCATE(AVG(languages), 1), COUNT(*) FROM test_emp GROUP BY YEAR(hire_date) HAVING ROUND(AVG(languages), 1) > 2.5 AND TRUNCATE(AVG(languages), 1) <= 3.0 ORDER BY YEAR(hire_date);
mi | ma | year |ROUND(AVG(languages),1)|TRUNCATE(AVG(languages),1)| COUNT(1)
-------------+-------------+---------------+-----------------------+--------------------------+--------------
26436 |74999 |1985 |3.1 |3.0 |11
25976 |74970 |1989 |3.1 |3.0 |13
31120 |71165 |1990 |3.1 |3.0 |12
32568 |65030 |1991 |2.8 |2.8 |6
30404 |58715 |1993 |3.0 |3.0 |3
35742 |67492 |1994 |2.8 |2.7 |4
28035 |65367 |1995 |2.6 |2.6 |5
45656 |45656 |1996 |3.0 |3.0 |1
64675 |64675 |1997 |3.0 |3.0 |1
;
// https://github.com/elastic/elasticsearch/issues/33773
minMaxRoundWithHavingRound-Ignore
SELECT MIN(salary) mi, MAX(salary) ma, YEAR(hire_date) year, ROUND(AVG(languages), 1), COUNT(*) FROM test_emp GROUP BY YEAR(hire_date) HAVING ROUND(AVG(languages), 1) > 2.5 ORDER BY YEAR(hire_date);
mi | ma | year |ROUND(AVG(languages),1)| COUNT(1)
-------------+-------------+---------------+-----------------------+--------------
26436 |74999 |1985 |3.1 |11
31897 |61805 |1986 |3.5 |11
25324 |70011 |1987 |3.1 |15
25945 |73578 |1988 |3.1 |9
25976 |74970 |1989 |3.1 |13
31120 |71165 |1990 |3.1 |12
32568 |65030 |1991 |2.8 |6
27215 |60781 |1992 |4.1 |8
30404 |58715 |1993 |3.0 |3
35742 |67492 |1994 |2.8 |4
28035 |65367 |1995 |2.6 |5
45656 |45656 |1996 |3.0 |1
64675 |64675 |1997 |3.0 |1
;
groupByAndOrderByTruncateWithPositiveParameter
SELECT TRUNCATE(AVG(salary), 2), AVG(salary), COUNT(*) FROM test_emp GROUP BY TRUNCATE(salary, 2) ORDER BY TRUNCATE(salary, 2) DESC LIMIT 10;
TRUNCATE(AVG(salary),2):i|AVG(salary):i | COUNT(1):l
-------------------------+---------------+---------------
74999 |74999 |1
74970 |74970 |1
74572 |74572 |1
73851 |73851 |1
73717 |73717 |1
73578 |73578 |1
71165 |71165 |1
70011 |70011 |1
69904 |69904 |1
68547 |68547 |1
;
groupByAndOrderByRoundWithPositiveParameter
SELECT ROUND(AVG(salary), 2), AVG(salary), COUNT(*) FROM test_emp GROUP BY ROUND(salary, 2) ORDER BY ROUND(salary, 2) DESC LIMIT 10;
ROUND(AVG(salary),2):i| AVG(salary):i | COUNT(1):l
----------------------+-----------------+---------------
74999 |74999 |1
74970 |74970 |1
74572 |74572 |1
73851 |73851 |1
73717 |73717 |1
73578 |73578 |1
71165 |71165 |1
70011 |70011 |1
69904 |69904 |1
68547 |68547 |1
;
groupByAndOrderByRoundWithNoSecondParameter
SELECT ROUND(AVG(salary)), ROUND(salary) rounded, AVG(salary), COUNT(*) FROM test_emp GROUP BY rounded ORDER BY rounded DESC LIMIT 10;
ROUND(AVG(salary),0):i| rounded:i | AVG(salary):i | COUNT(1):l
----------------------+-----------------+-----------------+---------------
74999 |74999 |74999 |1
74970 |74970 |74970 |1
74572 |74572 |74572 |1
73851 |73851 |73851 |1
73717 |73717 |73717 |1
73578 |73578 |73578 |1
71165 |71165 |71165 |1
70011 |70011 |70011 |1
69904 |69904 |69904 |1
68547 |68547 |68547 |1
;

View File

@ -62,7 +62,7 @@ mathRadians
SELECT RADIANS(emp_no) m, first_name FROM "test_emp" WHERE emp_no < 10010 ORDER BY emp_no; SELECT RADIANS(emp_no) m, first_name FROM "test_emp" WHERE emp_no < 10010 ORDER BY emp_no;
// end::radians // end::radians
mathRound mathRound
SELECT CAST(ROUND(emp_no) AS INT) m, first_name FROM "test_emp" WHERE emp_no < 10010 ORDER BY emp_no; SELECT CAST(ROUND(emp_no, 0) AS INT) m, first_name FROM "test_emp" WHERE emp_no < 10010 ORDER BY emp_no;
mathSign mathSign
// tag::sign // tag::sign
SELECT SIGN(emp_no) m, first_name FROM "test_emp" WHERE emp_no < 10010 ORDER BY emp_no; SELECT SIGN(emp_no) m, first_name FROM "test_emp" WHERE emp_no < 10010 ORDER BY emp_no;
@ -134,3 +134,48 @@ SELECT POWER(emp_no, 2) m, first_name FROM "test_emp" WHERE emp_no < 10010 ORDER
mathPowerNegative mathPowerNegative
SELECT POWER(salary, -1) m, first_name FROM "test_emp" WHERE emp_no < 10010 ORDER BY emp_no; SELECT POWER(salary, -1) m, first_name FROM "test_emp" WHERE emp_no < 10010 ORDER BY emp_no;
// end::power // end::power
roundInline1
SELECT ROUND(-345.123, -2) AS rounded;
roundInline2
SELECT ROUND(-345.123, 2) AS rounded;
roundInline3
SELECT ROUND(-345.123, 0) AS rounded;
roundInline4
SELECT ROUND(-345.123,-51231231) AS rounded;
roundInline5
SELECT ROUND(134.51, 1) AS rounded;
roundInline6
SELECT ROUND(134.56, 1) AS rounded;
roundInline7
SELECT ROUND(-345.123) AS rounded;
truncateInline1
SELECT TRUNCATE(-345.123, -2) AS trimmed;
truncateInline2
SELECT TRUNCATE(-345.123, 2) AS trimmed;
truncateInline3
SELECT TRUNCATE(-345.123, 0) AS trimmed;
truncateInline4
SELECT TRUNCATE(-345.123,-51231231) AS trimmed;
truncateInline5
SELECT TRUNCATE(134.51, 1) AS trimmed;
truncateInline6
SELECT TRUNCATE(134.56, 1) AS trimmed;
truncateInline7
SELECT TRUNCATE(-345.123) AS trimmed;
truncateAndRoundInline
SELECT ROUND(134.56,1) AS rounded, TRUNCATE(134.56,1) AS trimmed;