-
Notifications
You must be signed in to change notification settings - Fork 709
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
Optimizer: case insensitivity (#785)
- Loading branch information
Showing
5 changed files
with
144 additions
and
2 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,92 @@ | ||
from sqlglot import exp | ||
from sqlglot.helper import ensure_collection | ||
|
||
|
||
def lower_identities(expression): | ||
""" | ||
Convert all unquoted identifiers to lower case. | ||
Assuming the schema is all lower case, this essentially makes identifiers case-insensitive. | ||
Example: | ||
>>> import sqlglot | ||
>>> expression = sqlglot.parse_one('SELECT Bar.A AS A FROM "Foo".Bar') | ||
>>> lower_identities(expression).sql() | ||
'SELECT bar.a AS A FROM "Foo".bar' | ||
Args: | ||
expression (sqlglot.Expression): expression to quote | ||
Returns: | ||
sqlglot.Expression: quoted expression | ||
""" | ||
# We need to leave the output aliases unchanged, so the selects need special handling | ||
_lower_selects(expression) | ||
|
||
# These clauses can reference output aliases and also need special handling | ||
_lower_order(expression) | ||
_lower_having(expression) | ||
|
||
# We've already handled these args, so don't traverse into them | ||
traversed = {"expressions", "order", "having"} | ||
|
||
if isinstance(expression, exp.Subquery): | ||
# Root subquery, e.g. (SELECT A AS A FROM X) LIMIT 1 | ||
lower_identities(expression.this) | ||
traversed |= {"this"} | ||
|
||
if isinstance(expression, exp.Union): | ||
# Union, e.g. SELECT A AS A FROM X UNION SELECT A AS A FROM X | ||
lower_identities(expression.left) | ||
lower_identities(expression.right) | ||
traversed |= {"this", "expression"} | ||
|
||
for k, v in expression.args.items(): | ||
if k in traversed: | ||
continue | ||
|
||
for child in ensure_collection(v): | ||
if isinstance(child, exp.Expression): | ||
child.transform(_lower, copy=False) | ||
|
||
return expression | ||
|
||
|
||
def _lower_selects(expression): | ||
for e in expression.expressions: | ||
# Leave output aliases as-is | ||
e.unalias().transform(_lower, copy=False) | ||
|
||
|
||
def _lower_order(expression): | ||
order = expression.args.get("order") | ||
|
||
if not order: | ||
return | ||
|
||
output_aliases = {e.alias for e in expression.expressions if isinstance(e, exp.Alias)} | ||
|
||
for ordered in order.expressions: | ||
# Don't lower references to output aliases | ||
if not ( | ||
isinstance(ordered.this, exp.Column) | ||
and not ordered.this.table | ||
and ordered.this.name in output_aliases | ||
): | ||
ordered.transform(_lower, copy=False) | ||
|
||
|
||
def _lower_having(expression): | ||
having = expression.args.get("having") | ||
|
||
if not having: | ||
return | ||
|
||
# Don't lower references to output aliases | ||
for agg in having.find_all(exp.AggFunc): | ||
agg.transform(_lower, copy=False) | ||
|
||
|
||
def _lower(node): | ||
if isinstance(node, exp.Identifier) and not node.quoted: | ||
node.set("this", node.this.lower()) | ||
return node |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,41 @@ | ||
SELECT a FROM x; | ||
SELECT a FROM x; | ||
|
||
SELECT "A" FROM "X"; | ||
SELECT "A" FROM "X"; | ||
|
||
SELECT a AS A FROM x; | ||
SELECT a AS A FROM x; | ||
|
||
SELECT * FROM x; | ||
SELECT * FROM x; | ||
|
||
SELECT A FROM x; | ||
SELECT a FROM x; | ||
|
||
SELECT a FROM X; | ||
SELECT a FROM x; | ||
|
||
SELECT A AS A FROM (SELECT a AS A FROM x); | ||
SELECT a AS A FROM (SELECT a AS a FROM x); | ||
|
||
SELECT a AS B FROM x ORDER BY B; | ||
SELECT a AS B FROM x ORDER BY B; | ||
|
||
SELECT A FROM x ORDER BY A; | ||
SELECT a FROM x ORDER BY a; | ||
|
||
SELECT A AS B FROM X GROUP BY A HAVING SUM(B) > 0; | ||
SELECT a AS B FROM x GROUP BY a HAVING SUM(b) > 0; | ||
|
||
SELECT A AS B, SUM(B) AS C FROM X GROUP BY A HAVING C > 0; | ||
SELECT a AS B, SUM(b) AS C FROM x GROUP BY a HAVING C > 0; | ||
|
||
SELECT A FROM X UNION SELECT A FROM X; | ||
SELECT a FROM x UNION SELECT a FROM x; | ||
|
||
SELECT A AS A FROM X UNION SELECT A AS A FROM X; | ||
SELECT a AS A FROM x UNION SELECT a AS A FROM x; | ||
|
||
(SELECT A AS A FROM X); | ||
(SELECT a AS A FROM x); |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters