Skip to content

Conversation

@fivetran-felixhuang
Copy link
Collaborator

@fivetran-felixhuang fivetran-felixhuang commented Jan 23, 2026

For BOOLNOT, BOOLAND, BOOLOR and BOOLXOR, Snowflake rounds floating point inputs, while duckDB's boolean functions don't do rounding on the inputs. So BOOLAND(-0.4, 5) is evaluated to FALSE (same as BOOLAND(0, 5)) on Snowlfake, while its transpiled DuckDB query ((-0.4) AND (5)) is evaluated to TRUE. We should add rounding to the transpiled duckDB query.

The PR adds this rounding step when transpiling these functions from Snowflake to DuckDB.

Testing

Source query:

SELECT 
BOOLXOR(2, 0.3),
BOOLXOR(2, 3),
BOOLAND(-0.4, 5),
BOOLOR(2, 0.3),
BOOLNOT(0.1)

Transpiled query:

SELECT 
(ROUND(2, 0) AND (NOT ROUND(0.3, 0))) OR ((NOT ROUND(2, 0)) AND ROUND(0.3, 0)) AS "_col_0", 
(ROUND(2, 0) AND (NOT ROUND(3, 0))) OR ((NOT ROUND(2, 0)) AND ROUND(3, 0)) AS "_col_1", 
((ROUND(-0.4, 0)) AND (ROUND(5, 0))) AS "_col_2", 
((ROUND(2, 0)) OR (ROUND(0.3, 0))) AS "_col_3", 
NOT (ROUND(0.1, 0)) AS "_col_4"

Both queries produce the same result
TRUE | FALSE | FALSE | TRUE | TRUE

Without this change, the transpiled query produces

false │ false │ true │ true │ false

@github-actions
Copy link
Contributor

github-actions bot commented Jan 23, 2026

SQLGlot Integration Test Results

Comparing:

  • this branch (sqlglot:snowflake_to_duckdb_boolean_function_rounding, sqlglot version: snowflake_to_duckdb_boolean_function_rounding)
  • baseline (main, sqlglot version: 28.6.1.dev95)

⚠️ Limited to dialects: snowflake, duckdb

By Dialect

dialect main sqlglot:snowflake_to_duckdb_boolean_function_rounding difference links
duckdb -> duckdb 4003/4003 passed (100.0%) 4003/4003 passed (100.0%) No change full result / delta
snowflake -> duckdb 615/847 passed (72.6%) 615/847 passed (72.6%) No change full result / delta
snowflake -> snowflake 847/847 passed (100.0%) 847/847 passed (100.0%) No change full result / delta

Overall

main: 5697 total, 5465 passed (pass rate: 95.9%), sqlglot version: 28.6.1.dev95

sqlglot:snowflake_to_duckdb_boolean_function_rounding: 5697 total, 5465 passed (pass rate: 95.9%), sqlglot version: snowflake_to_duckdb_boolean_function_rounding

Difference: No change

Copy link
Collaborator

@geooo109 geooo109 left a comment

Choose a reason for hiding this comment

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

Nice work, and also great catch!

Comment on lines +1133 to +1165
def _boolnot_sql(self: DuckDB.Generator, expression: exp.Boolnot) -> str:
arg = expression.args.get("this")
if expression.args.get("round_input"):
arg = self.func("ROUND", arg, exp.Literal.number(0))
return f"NOT ({self.sql(arg)})"


def _booland_sql(self: DuckDB.Generator, expression: exp.Booland) -> str:
left = expression.args.get("this")
right = expression.args.get("expression")
if expression.args.get("round_input"):
left = self.func("ROUND", left, exp.Literal.number(0))
right = self.func("ROUND", right, exp.Literal.number(0))
return f"(({self.sql(left)}) AND ({self.sql(right)}))"


def _boolor_sql(self: DuckDB.Generator, expression: exp.Boolor) -> str:
left = expression.args.get("this")
right = expression.args.get("expression")
if expression.args.get("round_input"):
left = self.func("ROUND", left, exp.Literal.number(0))
right = self.func("ROUND", right, exp.Literal.number(0))
return f"(({self.sql(left)}) OR ({self.sql(right)}))"


def _xor_sql(self: DuckDB.Generator, expression: exp.Xor) -> str:
left = expression.args.get("this")
right = expression.args.get("expression")
if expression.args.get("round_input"):
left = self.func("ROUND", left, exp.Literal.number(0))
right = self.func("ROUND", right, exp.Literal.number(0))
return f"({self.sql(left)} AND (NOT {self.sql(right)})) OR ((NOT {self.sql(left)}) AND {self.sql(right)})"

Copy link
Collaborator

@geooo109 geooo109 Jan 25, 2026

Choose a reason for hiding this comment

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

Let's use the exp.Round for the call of the rounding function.
Moreover, let's use the expression builders for OR, AND, NOT, Paren.

We can also factor out the logic here for the rounding of each arg, and minimze the code of the functions.

Copy link
Collaborator

Choose a reason for hiding this comment

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

+1 – we should not be generating SQL by hand in cases like this where binary operators are involved. Instead, construct the proper AST and generate those via self.sql if possible, so that they'll be pretty-formatted when the user sets the option.

Copy link
Collaborator

@georgesittas georgesittas left a comment

Choose a reason for hiding this comment

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

Agreed with Geo's feedback, let's clean this up a bit and then we can merge.



def _boolnot_sql(self: DuckDB.Generator, expression: exp.Boolnot) -> str:
arg = expression.args.get("this")
Copy link
Collaborator

Choose a reason for hiding this comment

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

Suggested change
arg = expression.args.get("this")
arg = expression.this

Comment on lines +1141 to +1142
left = expression.args.get("this")
right = expression.args.get("expression")
Copy link
Collaborator

Choose a reason for hiding this comment

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

Suggested change
left = expression.args.get("this")
right = expression.args.get("expression")
left = expression.this
right = expression.expression

Comment on lines +1150 to +1151
left = expression.args.get("this")
right = expression.args.get("expression")
Copy link
Collaborator

Choose a reason for hiding this comment

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

Suggested change
left = expression.args.get("this")
right = expression.args.get("expression")
left = expression.this
right = expression.expression

Comment on lines +1159 to +1160
left = expression.args.get("this")
right = expression.args.get("expression")
Copy link
Collaborator

Choose a reason for hiding this comment

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

Suggested change
left = expression.args.get("this")
right = expression.args.get("expression")
left = expression.this
right = expression.expression

@georgesittas
Copy link
Collaborator

I'll take this to the finish line.

@georgesittas georgesittas merged commit 2f19d1d into main Jan 26, 2026
3 of 9 checks passed
@georgesittas georgesittas deleted the snowflake_to_duckdb_boolean_function_rounding branch January 26, 2026 10:21
georgesittas added a commit that referenced this pull request Jan 26, 2026
…functions to DuckDB (#6849)

Co-authored-by: Jo <46752250+georgesittas@users.noreply.github.com>
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.

3 participants