Skip to content

Commit 89fc63c

Browse files
authored
Fix(duckdb, clickhouse)!: QUALIFY comes after WINDOW clause in queries (#3745)
* Fix(duckdb): QUALIFY comes after WINDOW clause in queries * Refactor, don't eliminate qualify for clickhouse
1 parent 44977e9 commit 89fc63c

File tree

6 files changed

+18
-5
lines changed

6 files changed

+18
-5
lines changed

sqlglot/dialects/bigquery.py

+7
Original file line numberDiff line numberDiff line change
@@ -735,6 +735,13 @@ class Generator(generator.Generator):
735735
exp.VolatileProperty: exp.Properties.Location.UNSUPPORTED,
736736
}
737737

738+
# WINDOW comes after QUALIFY
739+
# https://cloud.google.com/bigquery/docs/reference/standard-sql/query-syntax#window_clause
740+
AFTER_HAVING_MODIFIER_TRANSFORMS = {
741+
"qualify": generator.Generator.AFTER_HAVING_MODIFIER_TRANSFORMS["qualify"],
742+
"windows": generator.Generator.AFTER_HAVING_MODIFIER_TRANSFORMS["windows"],
743+
}
744+
738745
# from: https://cloud.google.com/bigquery/docs/reference/standard-sql/lexical#reserved_keywords
739746
RESERVED_KEYWORDS = {
740747
"all",

sqlglot/dialects/clickhouse.py

+1-2
Original file line numberDiff line numberDiff line change
@@ -2,7 +2,7 @@
22

33
import typing as t
44

5-
from sqlglot import exp, generator, parser, tokens, transforms
5+
from sqlglot import exp, generator, parser, tokens
66
from sqlglot.dialects.dialect import (
77
Dialect,
88
arg_max_or_min_no_count,
@@ -789,7 +789,6 @@ class Generator(generator.Generator):
789789
exp.Quantile: _quantile_sql,
790790
exp.RegexpLike: lambda self, e: self.func("match", e.this, e.expression),
791791
exp.Rand: rename_func("randCanonical"),
792-
exp.Select: transforms.preprocess([transforms.eliminate_qualify]),
793792
exp.StartsWith: rename_func("startsWith"),
794793
exp.StrPosition: lambda self, e: self.func(
795794
"position", e.this, e.args.get("substr"), e.args.get("position")

sqlglot/generator.py

+1-1
Original file line numberDiff line numberDiff line change
@@ -406,13 +406,13 @@ class Generator(metaclass=_Generator):
406406
AFTER_HAVING_MODIFIER_TRANSFORMS = {
407407
"cluster": lambda self, e: self.sql(e, "cluster"),
408408
"distribute": lambda self, e: self.sql(e, "distribute"),
409-
"qualify": lambda self, e: self.sql(e, "qualify"),
410409
"sort": lambda self, e: self.sql(e, "sort"),
411410
"windows": lambda self, e: (
412411
self.seg("WINDOW ") + self.expressions(e, key="windows", flat=True)
413412
if e.args.get("windows")
414413
else ""
415414
),
415+
"qualify": lambda self, e: self.sql(e, "qualify"),
416416
}
417417

418418
TOKEN_MAPPING: t.Dict[TokenType, str] = {}

tests/dialects/test_clickhouse.py

+3
Original file line numberDiff line numberDiff line change
@@ -83,6 +83,9 @@ def test_clickhouse(self):
8383
self.validate_identity("TRUNCATE TABLE t1 ON CLUSTER test_cluster")
8484
self.validate_identity("TRUNCATE DATABASE db")
8585
self.validate_identity("TRUNCATE DATABASE db ON CLUSTER test_cluster")
86+
self.validate_identity(
87+
"SELECT number, COUNT() OVER (PARTITION BY number % 3) AS partition_count FROM numbers(10) WINDOW window_name AS (PARTITION BY number) QUALIFY partition_count = 4 ORDER BY number"
88+
)
8689
self.validate_identity(
8790
"SELECT id, quantileGK(100, 0.95)(reading) OVER (PARTITION BY id ORDER BY id RANGE BETWEEN 30000 PRECEDING AND CURRENT ROW) AS window FROM table"
8891
)

tests/dialects/test_dialect.py

+2-2
Original file line numberDiff line numberDiff line change
@@ -2267,7 +2267,7 @@ def test_qualify(self):
22672267
write={
22682268
"duckdb": "SELECT * FROM t QUALIFY COUNT(*) OVER () > 1",
22692269
"snowflake": "SELECT * FROM t QUALIFY COUNT(*) OVER () > 1",
2270-
"clickhouse": "SELECT * FROM (SELECT *, COUNT(*) OVER () AS _w FROM t) AS _t WHERE _w > 1",
2270+
"clickhouse": "SELECT * FROM t QUALIFY COUNT(*) OVER () > 1",
22712271
"mysql": "SELECT * FROM (SELECT *, COUNT(*) OVER () AS _w FROM t) AS _t WHERE _w > 1",
22722272
"oracle": "SELECT * FROM (SELECT *, COUNT(*) OVER () AS _w FROM t) _t WHERE _w > 1",
22732273
"postgres": "SELECT * FROM (SELECT *, COUNT(*) OVER () AS _w FROM t) AS _t WHERE _w > 1",
@@ -2279,7 +2279,7 @@ def test_qualify(self):
22792279
write={
22802280
"duckdb": 'SELECT "user id", some_id, 1 AS other_id, 2 AS "2 nd id" FROM t QUALIFY COUNT(*) OVER () > 1',
22812281
"snowflake": 'SELECT "user id", some_id, 1 AS other_id, 2 AS "2 nd id" FROM t QUALIFY COUNT(*) OVER () > 1',
2282-
"clickhouse": 'SELECT "user id", some_id, other_id, "2 nd id" FROM (SELECT "user id", some_id, 1 AS other_id, 2 AS "2 nd id", COUNT(*) OVER () AS _w FROM t) AS _t WHERE _w > 1',
2282+
"clickhouse": 'SELECT "user id", some_id, 1 AS other_id, 2 AS "2 nd id" FROM t QUALIFY COUNT(*) OVER () > 1',
22832283
"mysql": "SELECT `user id`, some_id, other_id, `2 nd id` FROM (SELECT `user id`, some_id, 1 AS other_id, 2 AS `2 nd id`, COUNT(*) OVER () AS _w FROM t) AS _t WHERE _w > 1",
22842284
"oracle": 'SELECT "user id", some_id, other_id, "2 nd id" FROM (SELECT "user id", some_id, 1 AS other_id, 2 AS "2 nd id", COUNT(*) OVER () AS _w FROM t) _t WHERE _w > 1',
22852285
"postgres": 'SELECT "user id", some_id, other_id, "2 nd id" FROM (SELECT "user id", some_id, 1 AS other_id, 2 AS "2 nd id", COUNT(*) OVER () AS _w FROM t) AS _t WHERE _w > 1',

tests/dialects/test_duckdb.py

+4
Original file line numberDiff line numberDiff line change
@@ -361,6 +361,10 @@ def test_duckdb(self):
361361
self.validate_identity(
362362
"SELECT * FROM (PIVOT Cities ON Year USING SUM(Population) GROUP BY Country) AS pivot_alias"
363363
)
364+
self.validate_identity(
365+
# QUALIFY comes after WINDOW
366+
"SELECT schema_name, function_name, ROW_NUMBER() OVER my_window AS function_rank FROM DUCKDB_FUNCTIONS() WINDOW my_window AS (PARTITION BY schema_name ORDER BY function_name) QUALIFY ROW_NUMBER() OVER my_window < 3"
367+
)
364368
self.validate_identity("DATE_SUB('YEAR', col, '2020-01-01')").assert_is(exp.Anonymous)
365369
self.validate_identity("DATESUB('YEAR', col, '2020-01-01')").assert_is(exp.Anonymous)
366370

0 commit comments

Comments
 (0)