Skip to content

Conversation

sim1984
Copy link

@sim1984 sim1984 commented Oct 9, 2025

The BIN_AND_AGG, BIN_OR_AGG, and BIN_XOR_AGG aggregate functions perform bit operations.

NULLs are ignored. It's returned only in the case of none evaluated records having a non-null value.

The input argument must be one of the integer types (SMALLINT, INTEGER, BIGINT, or INT128).
The output result is of the same type as the input argument.

Syntax:

<bin_add agg> ::= BIN_AND_AGG(<expression>)

<bin_or agg> ::= BIN_OR_AGG(<expression>)

<bin_xor agg> ::= BIN_XOR_AGG([ALL | DISTINCT] <expression>)

The BIN_AND_AGG and BIN_OR_AGG functions do not support the DISTINCT keyword, since eliminating duplicates does
not affect the result. However, for BIN_XOR_AGG, you can specify DISTINCT to exclude duplicates from processing.

Example:

SELECT
  name,
  BIN_AND_AGG(n) AS F_AND,
  BIN_OR_AGG(n) AS F_OR,
  BIN_XOR_AGG(n) AS F_XOR,
  BIN_XOR_AGG(ALL n) AS F_XOR_A,
  BIN_XOR_AGG(DISTINCT n) AS F_XOR_D
FROM acl_masks
GROUP BY name

@sim1984
Copy link
Author

sim1984 commented Oct 9, 2025

This is related to #8175

In MySQL and PostgreSQL, these functions are called BIT_AND, BIT_OR, and BIT_XOR. But since we already have non-aggregate functions like BIN_AND, BIN_OR, and BIN_XOR, I decided to keep the names consistent.

<bin_or agg> ::= BIN_OR_AGG(<expression>)
<bin_xor agg> ::= BIN_XOR_AGG([ALL | DISTINCT] <expression>)
Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

What is a real use case for BIN_XOR_AGG?

Copy link
Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Personally, BIN_AND_AGG and BIN_OR_AGG would have been enough for me. But since MySQL and PostgreSQL have BIT_XOR, I decided to add a similar function to Firebird.

Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Aggregate XOR could be used for some trivial hashing (dangerous but fast). Or (probably more useful) for combining multiple already calculated hashes -- e.g. every row is hashed independently and then row hashes are aggregated using XOR.

@sim1984
Copy link
Author

sim1984 commented Oct 10, 2025

Thanks for the review. I'll fix it.

`NULLs` are ignored. It's returned only in the case of none evaluated records having a non-null value.

The input argument must be one of the integer types (`SMALLINT`, `INTEGER`, `BIGINT`, or `INT128`).
The output result is of the same type as the input argument.
Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

But in the code I see that SMALLINT and INTEGER are converted to BIGINT...

Copy link
Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

CREATE TABLE FLAGS (
  ID BIGINT GENERATED BY DEFAULT AS IDENTITY,
  S_FLAG SMALLINT,
  I_FLAG INTEGER,
  I64_FLAG BIGINT,
  I128_FLAG INT128,
  CONSTRAINT PK_FLAGS PRIMARY KEY(ID)
);

INSERT INTO FLAGS (S_FLAG, I_FLAG, I64_FLAG, I128_FLAG)
VALUES (1, 1, 1, 1);

INSERT INTO FLAGS (S_FLAG, I_FLAG, I64_FLAG, I128_FLAG)
VALUES (3, 3, 3, 3);

INSERT INTO FLAGS (S_FLAG, I_FLAG, I64_FLAG, I128_FLAG)
VALUES (8, 8, 8, 8);

INSERT INTO FLAGS (S_FLAG, I_FLAG, I64_FLAG, I128_FLAG)
VALUES (8, 8, 8, 8);

COMMIT;

SET SQLDA_DISPLAY ON;

SELECT
  BIN_OR_AGG(S_FLAG) AS S,
  BIN_OR_AGG(I_FLAG) AS I,
  BIN_OR_AGG(I64_FLAG) AS I64,
  BIN_OR_AGG(I128_FLAG) AS I128
FROM FLAGS;
INPUT message field count: 0

OUTPUT message field count: 4
01: sqltype: 500 SHORT Nullable scale: 0 subtype: 0 len: 2
  :  name: BIN_OR_AGG  alias: S
  : table:   schema:   owner:
02: sqltype: 496 LONG Nullable scale: 0 subtype: 0 len: 4
  :  name: BIN_OR_AGG  alias: I
  : table:   schema:   owner:
03: sqltype: 580 INT64 Nullable scale: 0 subtype: 0 len: 8
  :  name: BIN_OR_AGG  alias: I64
  : table:   schema:   owner:
04: sqltype: 32752 INT128 Nullable scale: 0 subtype: 0 len: 16
  :  name: BIN_OR_AGG  alias: I128
  : table:   schema:   owner:

      S            I                   I64                                          I128
======= ============ ===================== =============================================
     11           11                    11                                            11

@sim1984 sim1984 requested a review from asfernandes October 10, 2025 17:08
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment

Labels

None yet

Projects

None yet

Development

Successfully merging this pull request may close these issues.

4 participants