Skip to content

Commit

Permalink
IGNITE-23624 SQL Calcite: Add support for bitwise aggregates (BIT_AND…
Browse files Browse the repository at this point in the history
…, BIT_OR, BIT_XOR) - Fixes #11649.

Signed-off-by: Aleksey Plekhanov <plehanov.alex@gmail.com>
  • Loading branch information
Vladsz83 authored and alex-plekhanov committed Nov 20, 2024
1 parent ec498dd commit 8506646
Show file tree
Hide file tree
Showing 9 changed files with 292 additions and 19 deletions.
2 changes: 1 addition & 1 deletion docs/_docs/SQL/sql-calcite.adoc
Original file line number Diff line number Diff line change
Expand Up @@ -144,7 +144,7 @@ The Calcite-based SQL engine currently supports:
|Group | Functions list

|Aggregate functions
|`COUNT`, `SUM`, `AVG`, `MIN`, `MAX`, `ANY_VALUE`, `LISTAGG`, `GROUP_CONCAT`, `STRING_AGG`, `ARRAY_AGG`, `ARRAY_CONCAT_AGG`, `EVERY`, `SOME`
|`COUNT`, `SUM`, `AVG`, `MIN`, `MAX`, `ANY_VALUE`, `LISTAGG`, `GROUP_CONCAT`, `STRING_AGG`, `ARRAY_AGG`, `ARRAY_CONCAT_AGG`, `EVERY`, `SOME`, `BIT_AND`, `BIT_OR`, `BIT_XOR`

|String functions
|`UPPER`, `LOWER`, `INITCAP`, `TO_BASE64`, `FROM_BASE64`, `MD5`, `SHA1`, `SUBSTRING`, `LEFT`, `RIGHT`, `REPLACE`, `TRANSLATE`, `CHR`, `CHAR_LENGTH`, `CHARACTER_LENGTH`, `LENGTH`, `CONCAT`, `OVERLAY`, `POSITION`, `ASCII`, `REPEAT`, `SPACE`, `STRCMP`, `SOUNDEX`, `DIFFERENCE`, `REVERSE`, `TRIM`, `LTRIM`, `RTRIM`, `REGEXP_REPLACE`
Expand Down
15 changes: 15 additions & 0 deletions docs/_docs/sql-reference/aggregate-functions.adoc
Original file line number Diff line number Diff line change
Expand Up @@ -68,6 +68,21 @@ A logical OR operation is performed on each pair of corresponding bits of two bi

In each pair, the result is 1 if the first bit is 1 OR the second bit is 1 OR both bits are 1, and otherwise the result is 0.


== BIT_XOR


[source,sql]
----
BIT_XOR (expression)
----

The bitwise XOR of all non-null values. If no rows are selected, the result is NULL. Aggregates are only allowed in select statements.

A logical XOR operation is performed on each pair of corresponding bits of two binary expressions of equal length.

In each pair, the result is 1 if only one of the bits is 1. Otherwise the result is 0.

////
== BOOL_AND
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -33,6 +33,7 @@
import org.apache.calcite.rel.type.RelDataType;
import org.apache.calcite.rex.RexLiteral;
import org.apache.calcite.rex.RexNode;
import org.apache.calcite.sql.SqlKind;
import org.apache.ignite.internal.processors.query.calcite.exec.ExecutionContext;
import org.apache.ignite.internal.processors.query.calcite.exec.RowHandler;
import org.apache.ignite.internal.processors.query.calcite.type.IgniteTypeFactory;
Expand Down Expand Up @@ -94,6 +95,10 @@ private static <Row> Supplier<Accumulator<Row>> accumulatorFunctionFactory(
case "ARRAY_AGG":
case "ARRAY_CONCAT_AGG":
return listAggregateSupplier(call, ctx);
case "BIT_AND":
case "BIT_OR":
case "BIT_XOR":
return bitWiseFactory(call, hnd);
default:
throw new AssertionError(call.getAggregation().getName());
}
Expand Down Expand Up @@ -143,6 +148,21 @@ private static <Row> Supplier<Accumulator<Row>> avgFactory(AggregateCall call, R
}
}

/** */
private static <Row> Supplier<Accumulator<Row>> bitWiseFactory(AggregateCall call, RowHandler<Row> hnd) {
switch (call.type.getSqlTypeName()) {
case BIGINT:
case INTEGER:
case SMALLINT:
case TINYINT:
case NULL:
return () -> new BitWise<>(call, hnd);

default:
throw new UnsupportedOperationException(call.getName() + " is not supported for type '" + call.type + "'.");
}
}

/** */
private static <Row> Supplier<Accumulator<Row>> sumFactory(AggregateCall call, RowHandler<Row> hnd) {
switch (call.type.getSqlTypeName()) {
Expand Down Expand Up @@ -399,6 +419,82 @@ private static class AnyVal<Row> extends AbstractAccumulator<Row> {
}
}

/** */
private static class BitWise<Row> extends AbstractAccumulator<Row> {
/** */
private long res;

/** */
private boolean updated;

/** */
private final SqlKind kind;

/** */
private BitWise(AggregateCall aggCall, RowHandler<Row> hnd) {
super(aggCall, hnd);

kind = aggCall.getAggregation().kind;

assert kind == SqlKind.BIT_AND || kind == SqlKind.BIT_OR || kind == SqlKind.BIT_XOR;
}

/** {@inheritDoc} */
@Override public void add(Row row) {
Number in = get(0, row);

if (in == null)
return;

apply(in.longValue());
}

/** */
private void apply(long val) {
if (updated) {
switch (kind) {
case BIT_AND:
res &= val;
break;
case BIT_OR:
res |= val;
break;
case BIT_XOR:
res ^= val;
break;
}
}
else {
res = val;

updated = true;
}
}

/** {@inheritDoc} */
@Override public void apply(Accumulator<Row> other) {
BitWise<Row> other0 = (BitWise<Row>)other;

if (other0.updated)
apply(other0.res);
}

/** {@inheritDoc} */
@Override public Object end() {
return updated ? res : null;
}

/** {@inheritDoc} */
@Override public List<RelDataType> argumentTypes(IgniteTypeFactory typeFactory) {
return F.asList(typeFactory.createTypeWithNullability(typeFactory.createSqlType(BIGINT), true));
}

/** {@inheritDoc} */
@Override public RelDataType returnType(IgniteTypeFactory typeFactory) {
return typeFactory.createTypeWithNullability(typeFactory.createSqlType(BIGINT), true);
}
}

/** */
private static class DecimalAvg<Row> extends AbstractAccumulator<Row> {
/** */
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -429,6 +429,9 @@ private void validateAggregateFunction(SqlCall call, SqlAggFunction aggFunction)
case GROUP_CONCAT:
case LISTAGG:
case STRING_AGG:
case BIT_AND:
case BIT_OR:
case BIT_XOR:
return;
default:
throw newValidationError(call,
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -309,5 +309,10 @@ public IgniteStdSqlOperatorTable() {
register(SqlStdOperatorTable.CURRENT_DATE);
register(SqlStdOperatorTable.LOCALTIME);
register(SqlStdOperatorTable.LOCALTIMESTAMP);

// Bit wise operations.
register(SqlStdOperatorTable.BIT_AND);
register(SqlStdOperatorTable.BIT_OR);
register(SqlStdOperatorTable.BIT_XOR);
}
}
Original file line number Diff line number Diff line change
Expand Up @@ -174,6 +174,172 @@ public void testGroupingByAlias() {
.check();
}

/** */
@Test
public void testBitwiseTypesBounds() {
sql("CREATE TABLE tbl (t TINYINT, s SMALLINT, i INT, b BIGINT) WITH " + atomicity());

sql("INSERT INTO tbl values (?, ?, ?, ?)", Byte.MAX_VALUE, 0, 1000, 0);
sql("INSERT INTO tbl values (?, ?, ?, ?)", Byte.MIN_VALUE, 0, 1001, 0);
sql("INSERT INTO tbl values (?, ?, ?, ?)", 0, Short.MAX_VALUE, 1002, 0);
sql("INSERT INTO tbl values (?, ?, ?, ?)", 0, Short.MIN_VALUE, 1003, 0);
sql("INSERT INTO tbl values (?, ?, ?, ?)", 0, 0, Integer.MIN_VALUE, 0);
sql("INSERT INTO tbl values (?, ?, ?, ?)", 0, 0, Integer.MAX_VALUE, 0);
sql("INSERT INTO tbl values (?, ?, ?, ?)", 0, 0, 1006, Long.MAX_VALUE);
sql("INSERT INTO tbl values (?, ?, ?, ?)", 0, 0, 1007, Long.MIN_VALUE);

assertQuery("SELECT BIT_AND(t) FROM tbl WHERE i=? or i=?").withParams(1000, 1001).returns((byte)0).check();
assertQuery("SELECT BIT_OR(t) FROM tbl WHERE i=? or i=?").withParams(1000, 1001).returns((byte)-1).check();
assertQuery("SELECT BIT_XOR(t) FROM tbl WHERE i=? or i=?").withParams(1000, 1001).returns((byte)-1).check();

assertQuery("SELECT BIT_AND(s) FROM tbl WHERE i=? or i=?").withParams(1002, 1003).returns((short)0).check();
assertQuery("SELECT BIT_OR(s) FROM tbl WHERE i=? or i=?").withParams(1002, 1003).returns((short)-1).check();
assertQuery("SELECT BIT_XOR(s) FROM tbl WHERE i=? or i=?").withParams(1002, 1003).returns((short)-1).check();

assertQuery("SELECT BIT_AND(i) FROM tbl WHERE i=? or i=?").withParams(Integer.MAX_VALUE, Integer.MIN_VALUE)
.returns(0).check();
assertQuery("SELECT BIT_OR(i) FROM tbl WHERE i=? or i=?").withParams(Integer.MAX_VALUE, Integer.MIN_VALUE)
.returns(-1).check();
assertQuery("SELECT BIT_XOR(i) FROM tbl WHERE i=? or i=?").withParams(Integer.MAX_VALUE, Integer.MIN_VALUE)
.returns(-1).check();

assertQuery("SELECT BIT_AND(b) FROM tbl WHERE i=? or i=?").withParams(1006, 1007).returns(0L).check();
assertQuery("SELECT BIT_OR(b) FROM tbl WHERE i=? or i=?").withParams(1006, 1007).returns(-1L).check();
assertQuery("SELECT BIT_XOR(b) FROM tbl WHERE i=? or i=?").withParams(1006, 1007).returns(-1L).check();
}

/** */
@Test
public void testBitwiseBasics() {
sql("CREATE TABLE tbl (t TINYINT, s SMALLINT, i INT, b BIGINT) WITH " + atomicity());

for (int i = 0; i < 10; ++i)
sql("INSERT INTO tbl values (?, ?, ?, ?)", i, i, i, i);

sql("INSERT INTO tbl values (null, null, null, null)");

for (String op : F.asList("AND", "OR", "XOR")) {
// Check dynamic parameter.
assertQuery("SELECT BIT_" + op + "(?)").withParams((byte)1).returns((byte)1).check();
assertQuery("SELECT BIT_" + op + "(?)").withParams((short)1).returns((short)1).check();
assertQuery("SELECT BIT_" + op + "(?)").withParams(1).returns(1).check();
assertQuery("SELECT BIT_" + op + "(?)").withParams(1L).returns(1L).check();

// Check 1 value.
assertQuery("SELECT BIT_" + op + "(t) FROM tbl WHERE i=1").returns((byte)1).check();
assertQuery("SELECT BIT_" + op + "(s) FROM tbl WHERE i=1").returns((short)1).check();
assertQuery("SELECT BIT_" + op + "(i) FROM tbl WHERE i=1").returns(1).check();
assertQuery("SELECT BIT_" + op + "(b) FROM tbl WHERE i=1").returns(1L).check();

// Check nulls.
assertQuery("SELECT BIT_" + op + "(t) FROM tbl WHERE t is null").returns(NULL_RESULT).check();
assertQuery("SELECT BIT_" + op + "(s) FROM tbl WHERE s is null").returns(NULL_RESULT).check();
assertQuery("SELECT BIT_" + op + "(i) FROM tbl WHERE i is null").returns(NULL_RESULT).check();
assertQuery("SELECT BIT_" + op + "(b) FROM tbl WHERE b is null").returns(NULL_RESULT).check();

// Check 1 value and null.
assertQuery("SELECT BIT_" + op + "(t) FROM tbl WHERE i=1 or i is null").returns((byte)1).check();
assertQuery("SELECT BIT_" + op + "(s) FROM tbl WHERE i=1 or i is null").returns((short)1).check();
assertQuery("SELECT BIT_" + op + "(i) FROM tbl WHERE i=1 or i is null").returns(1).check();
assertQuery("SELECT BIT_" + op + "(b) FROM tbl WHERE i=1 or i is null").returns(1L).check();

// Check not existing.
for (String col : F.asList("t", "s", "i", "b", "t + s", "s + i", "i + b"))
assertQuery("SELECT BIT_" + op + "(" + col + ") FROM tbl WHERE i=200").returns(NULL_RESULT).check();
}
}

/** */
@Test
public void testBitwiseLeastRestrictive() {
sql("CREATE TABLE tbl (t TINYINT, s SMALLINT, i INT, b BIGINT) WITH " + atomicity());

for (int i = 0; i < 10; ++i)
sql("INSERT INTO tbl values (?, ?, ?, ?)", i, i, i, i);

// Check least restrictive.
assertQuery("SELECT BIT_AND(t + s) FROM tbl WHERE i=1 or i=7 or i=200").returns((short)2).check();
assertQuery("SELECT BIT_AND(s + i) FROM tbl WHERE i=1 or i=7 or i=200").returns(2).check();
assertQuery("SELECT BIT_AND(i + b) FROM tbl WHERE i=1 or i=7 or i=200").returns(2L).check();

assertQuery("SELECT BIT_OR(t + s) FROM tbl WHERE i=2 or i=4 or i=200").returns((short)12).check();
assertQuery("SELECT BIT_OR(s + i) FROM tbl WHERE i=2 or i=4 or i=200").returns(12).check();
assertQuery("SELECT BIT_OR(i + b) FROM tbl WHERE i=2 or i=4 or i=200").returns(12L).check();

assertQuery("SELECT BIT_XOR(t + s) FROM tbl WHERE i=6 or i=2 or i=200").returns((short)8).check();
assertQuery("SELECT BIT_XOR(s + i) FROM tbl WHERE i=6 or i=2 or i=200").returns(8).check();
assertQuery("SELECT BIT_XOR(i + b) FROM tbl WHERE i=6 or i=2 or i=200").returns(8L).check();
}

/** */
@Test
public void testBitwiseGrouping() {
sql("CREATE TABLE tbl (g INT, i INT) WITH " + atomicity());

for (int i = 0; i < 3; ++i) {
sql("INSERT INTO tbl values (?, ?)", i, null);

for (int j = 0; j < 9; ++j)
sql("INSERT INTO tbl values (?, ?)", i, j);
}

assertQuery("SELECT g + 1, BIT_AND(i) from tbl where i in (3,7) group by g")
.returns(1, 3)
.returns(2, 3)
.returns(3, 3)
.check();

assertQuery("SELECT g + 1, BIT_OR(i) from tbl group by g")
.returns(1, 15)
.returns(2, 15)
.returns(3, 15)
.check();

assertQuery("SELECT g + 1, BIT_XOR(i) from tbl where i in (1,2,4,8) group by g")
.returns(1, 15)
.returns(2, 15)
.returns(3, 15)
.check();
}

/** */
@Test
public void testBitwiseResults() {
sql("CREATE TABLE tbl (t TINYINT, s SMALLINT, i INT, b BIGINT) WITH " + atomicity());

for (int i = 0; i < 10; ++i)
sql("INSERT INTO tbl values (?, ?, ?, ?)", i, i, i, i);

assertQuery("SELECT BIT_AND(t) FROM tbl WHERE i BETWEEN 2 and 3 or i=200").returns((byte)2).check();
assertQuery("SELECT BIT_AND(s) FROM tbl WHERE i BETWEEN 2 and 3 or i=200").returns((short)2).check();
assertQuery("SELECT BIT_AND(i) FROM tbl WHERE i BETWEEN 2 and 3 or i=200").returns(2).check();
assertQuery("SELECT BIT_AND(b) FROM tbl WHERE i BETWEEN 2 and 3 or i=200").returns(2L).check();

assertQuery("SELECT BIT_XOR(t) FROM tbl WHERE i=8 or i=9 or i=200").returns((byte)1).check();
assertQuery("SELECT BIT_XOR(s) FROM tbl WHERE i=8 or i=9 or i=200").returns((short)1).check();
assertQuery("SELECT BIT_XOR(i) FROM tbl WHERE i=8 or i=9 or i=200").returns(1).check();
assertQuery("SELECT BIT_XOR(b) FROM tbl WHERE i=8 or i=9 or i=200").returns(1L).check();

assertQuery("SELECT BIT_OR(t) FROM tbl WHERE i=8 or i=1 or i=200").returns((byte)9).check();
assertQuery("SELECT BIT_OR(s) FROM tbl WHERE i=8 or i=1 or i=200").returns((short)9).check();
assertQuery("SELECT BIT_OR(i) FROM tbl WHERE i=8 or i=1 or i=200").returns(9).check();
assertQuery("SELECT BIT_OR(b) FROM tbl WHERE i=8 or i=1 or i=200").returns(9L).check();

for (String op : F.asList("AND", "XOR")) {
String where = "AND".equals(op) ? "i<100" : "i=7 or i=4 or i=2 or i=1";

assertQuery("SELECT BIT_" + op + "(t) FROM tbl WHERE " + where).returns((byte)0).check();
assertQuery("SELECT BIT_" + op + "(s) FROM tbl WHERE " + where).returns((short)0).check();
assertQuery("SELECT BIT_" + op + "(i) FROM tbl WHERE " + where).returns(0).check();
assertQuery("SELECT BIT_" + op + "(b) FROM tbl WHERE " + where).returns(0L).check();
}

sql("INSERT INTO tbl values (1, 1, 1, 1)");

assertQuery("SELECT BIT_XOR(i) from tbl where i=1").returns(0).check();
assertQuery("SELECT BIT_XOR(DISTINCT i) from tbl where i=1").returns(1).check();
}

/** */
@Test
public void testCountOfNonNumericField() {
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -10,17 +10,13 @@ SELECT BIT_AND(3), BIT_AND(NULL)
3
NULL

# test on a sequence
statement ok
CREATE SEQUENCE seq;

query I
SELECT BIT_AND(nextval('seq'))
SELECT BIT_AND(1)
----
1

query I
SELECT BIT_AND(nextval('seq'))
SELECT BIT_AND(2)
----
2

Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -10,17 +10,13 @@ SELECT BIT_OR(3), BIT_OR(NULL)
3
NULL

# test on a sequence
statement ok
CREATE SEQUENCE seq;

query I
SELECT BIT_OR(nextval('seq'))
SELECT BIT_OR(1)
----
1

query I
SELECT BIT_OR(nextval('seq'))
SELECT BIT_OR(2)
----
2

Expand Down
Loading

0 comments on commit 8506646

Please sign in to comment.