Skip to content

Commit

Permalink
Fix(clickhouse)!: dont parse right-hand side operands of ARRAY JOIN a…
Browse files Browse the repository at this point in the history
…s Tables (#4258)

* Fix(clickhouse)!: dont parse right-hand side operands of ARRAY JOIN as Tables

* Refactor, address PR feedback
  • Loading branch information
georgesittas authored Oct 17, 2024
1 parent 51f4d26 commit 7fc0055
Show file tree
Hide file tree
Showing 4 changed files with 47 additions and 9 deletions.
6 changes: 6 additions & 0 deletions sqlglot/dialects/clickhouse.py
Original file line number Diff line number Diff line change
Expand Up @@ -603,6 +603,12 @@ def _parse_join(
if join:
join.set("global", join.args.pop("method", None))

# tbl ARRAY JOIN arr <-- this should be a `Column` reference, not a `Table`
# https://clickhouse.com/docs/en/sql-reference/statements/select/array-join
if join.kind == "ARRAY":
for table in join.find_all(exp.Table):
table.replace(table.to_column())

return join

def _parse_function(
Expand Down
10 changes: 9 additions & 1 deletion sqlglot/expressions.py
Original file line number Diff line number Diff line change
Expand Up @@ -3214,10 +3214,18 @@ def parts(self) -> t.List[Expression]:

def to_column(self, copy: bool = True) -> Alias | Column | Dot:
parts = self.parts
col = column(*reversed(parts[0:4]), fields=parts[4:], copy=copy) # type: ignore
last_part = parts[-1]

if isinstance(last_part, Identifier):
col = column(*reversed(parts[0:4]), fields=parts[4:], copy=copy) # type: ignore
else:
# This branch will be reached if a function or array is wrapped in a `Table`
col = last_part

alias = self.args.get("alias")
if alias:
col = alias_(col, alias.this, copy=copy)

return col


Expand Down
35 changes: 27 additions & 8 deletions tests/dialects/test_clickhouse.py
Original file line number Diff line number Diff line change
Expand Up @@ -421,14 +421,6 @@ def test_clickhouse(self):
" GROUP BY loyalty ORDER BY loyalty ASC"
},
)
self.validate_identity("SELECT s, arr FROM arrays_test ARRAY JOIN arr")
self.validate_identity("SELECT s, arr, a FROM arrays_test LEFT ARRAY JOIN arr AS a")
self.validate_identity(
"SELECT s, arr_external FROM arrays_test ARRAY JOIN [1, 2, 3] AS arr_external"
)
self.validate_identity(
"SELECT * FROM tbl ARRAY JOIN [1, 2, 3] AS arr_external1, ['a', 'b', 'c'] AS arr_external2, splitByString(',', 'asd,qwerty,zxc') AS arr_external3"
)
self.validate_all(
"SELECT quantile(0.5)(a)",
read={"duckdb": "SELECT quantile(a, 0.5)"},
Expand Down Expand Up @@ -1104,3 +1096,30 @@ def test_convert(self):
def test_grant(self):
self.validate_identity("GRANT SELECT(x, y) ON db.table TO john WITH GRANT OPTION")
self.validate_identity("GRANT INSERT(x, y) ON db.table TO john")

def test_array_join(self):
expr = self.validate_identity(
"SELECT * FROM arrays_test ARRAY JOIN arr1, arrays_test.arr2 AS foo, ['a', 'b', 'c'] AS elem"
)
joins = expr.args["joins"]
self.assertEqual(len(joins), 1)

join = joins[0]
self.assertEqual(join.kind, "ARRAY")
self.assertIsInstance(join.this, exp.Column)

self.assertEqual(len(join.expressions), 2)
self.assertIsInstance(join.expressions[0], exp.Alias)
self.assertIsInstance(join.expressions[0].this, exp.Column)

self.assertIsInstance(join.expressions[1], exp.Alias)
self.assertIsInstance(join.expressions[1].this, exp.Array)

self.validate_identity("SELECT s, arr FROM arrays_test ARRAY JOIN arr")
self.validate_identity("SELECT s, arr, a FROM arrays_test LEFT ARRAY JOIN arr AS a")
self.validate_identity(
"SELECT s, arr_external FROM arrays_test ARRAY JOIN [1, 2, 3] AS arr_external"
)
self.validate_identity(
"SELECT * FROM arrays_test ARRAY JOIN [1, 2, 3] AS arr_external1, ['a', 'b', 'c'] AS arr_external2, splitByString(',', 'asd,qwerty,zxc') AS arr_external3"
)
5 changes: 5 additions & 0 deletions tests/fixtures/optimizer/qualify_columns.sql
Original file line number Diff line number Diff line change
Expand Up @@ -196,6 +196,11 @@ SELECT SOME_UDF(t.data).* FROM t AS t;
SELECT a + 1 AS i, missing_column FROM x;
SELECT x.a + 1 AS i, missing_column AS missing_column FROM x AS x;

# execute: false
# dialect: clickhouse
SELECT s, arr1, arr2 FROM arrays_test LEFT ARRAY JOIN arr1, arrays_test.arr2;
SELECT arrays_test.s AS s, arrays_test.arr1 AS arr1, arrays_test.arr2 AS arr2 FROM arrays_test AS arrays_test LEFT ARRAY JOIN arrays_test.arr1, arrays_test.arr2;

--------------------------------------
-- Derived tables
--------------------------------------
Expand Down

0 comments on commit 7fc0055

Please sign in to comment.