Edit on GitHub

sqlglot.optimizer.merge_subqueries

  1from collections import defaultdict
  2
  3from sqlglot import expressions as exp
  4from sqlglot.helper import find_new_name
  5from sqlglot.optimizer.scope import Scope, traverse_scope
  6
  7
  8def merge_subqueries(expression, leave_tables_isolated=False):
  9    """
 10    Rewrite sqlglot AST to merge derived tables into the outer query.
 11
 12    This also merges CTEs if they are selected from only once.
 13
 14    Example:
 15        >>> import sqlglot
 16        >>> expression = sqlglot.parse_one("SELECT a FROM (SELECT x.a FROM x) CROSS JOIN y")
 17        >>> merge_subqueries(expression).sql()
 18        'SELECT x.a FROM x CROSS JOIN y'
 19
 20    If `leave_tables_isolated` is True, this will not merge inner queries into outer
 21    queries if it would result in multiple table selects in a single query:
 22        >>> expression = sqlglot.parse_one("SELECT a FROM (SELECT x.a FROM x) CROSS JOIN y")
 23        >>> merge_subqueries(expression, leave_tables_isolated=True).sql()
 24        'SELECT a FROM (SELECT x.a FROM x) CROSS JOIN y'
 25
 26    Inspired by https://dev.mysql.com/doc/refman/8.0/en/derived-table-optimization.html
 27
 28    Args:
 29        expression (sqlglot.Expression): expression to optimize
 30        leave_tables_isolated (bool):
 31    Returns:
 32        sqlglot.Expression: optimized expression
 33    """
 34    expression = merge_ctes(expression, leave_tables_isolated)
 35    expression = merge_derived_tables(expression, leave_tables_isolated)
 36    return expression
 37
 38
 39# If a derived table has these Select args, it can't be merged
 40UNMERGABLE_ARGS = set(exp.Select.arg_types) - {
 41    "expressions",
 42    "from",
 43    "joins",
 44    "where",
 45    "order",
 46    "hint",
 47}
 48
 49
 50def merge_ctes(expression, leave_tables_isolated=False):
 51    scopes = traverse_scope(expression)
 52
 53    # All places where we select from CTEs.
 54    # We key on the CTE scope so we can detect CTES that are selected from multiple times.
 55    cte_selections = defaultdict(list)
 56    for outer_scope in scopes:
 57        for table, inner_scope in outer_scope.selected_sources.values():
 58            if isinstance(inner_scope, Scope) and inner_scope.is_cte:
 59                cte_selections[id(inner_scope)].append(
 60                    (
 61                        outer_scope,
 62                        inner_scope,
 63                        table,
 64                    )
 65                )
 66
 67    singular_cte_selections = [v[0] for k, v in cte_selections.items() if len(v) == 1]
 68    for outer_scope, inner_scope, table in singular_cte_selections:
 69        from_or_join = table.find_ancestor(exp.From, exp.Join)
 70        if _mergeable(outer_scope, inner_scope, leave_tables_isolated, from_or_join):
 71            alias = table.alias_or_name
 72            _rename_inner_sources(outer_scope, inner_scope, alias)
 73            _merge_from(outer_scope, inner_scope, table, alias)
 74            _merge_expressions(outer_scope, inner_scope, alias)
 75            _merge_joins(outer_scope, inner_scope, from_or_join)
 76            _merge_where(outer_scope, inner_scope, from_or_join)
 77            _merge_order(outer_scope, inner_scope)
 78            _merge_hints(outer_scope, inner_scope)
 79            _pop_cte(inner_scope)
 80            outer_scope.clear_cache()
 81    return expression
 82
 83
 84def merge_derived_tables(expression, leave_tables_isolated=False):
 85    for outer_scope in traverse_scope(expression):
 86        for subquery in outer_scope.derived_tables:
 87            from_or_join = subquery.find_ancestor(exp.From, exp.Join)
 88            alias = subquery.alias_or_name
 89            inner_scope = outer_scope.sources[alias]
 90            if _mergeable(outer_scope, inner_scope, leave_tables_isolated, from_or_join):
 91                _rename_inner_sources(outer_scope, inner_scope, alias)
 92                _merge_from(outer_scope, inner_scope, subquery, alias)
 93                _merge_expressions(outer_scope, inner_scope, alias)
 94                _merge_joins(outer_scope, inner_scope, from_or_join)
 95                _merge_where(outer_scope, inner_scope, from_or_join)
 96                _merge_order(outer_scope, inner_scope)
 97                _merge_hints(outer_scope, inner_scope)
 98                outer_scope.clear_cache()
 99    return expression
100
101
102def _mergeable(outer_scope, inner_scope, leave_tables_isolated, from_or_join):
103    """
104    Return True if `inner_select` can be merged into outer query.
105
106    Args:
107        outer_scope (Scope)
108        inner_scope (Scope)
109        leave_tables_isolated (bool)
110        from_or_join (exp.From|exp.Join)
111    Returns:
112        bool: True if can be merged
113    """
114    inner_select = inner_scope.expression.unnest()
115
116    def _is_a_window_expression_in_unmergable_operation():
117        window_expressions = inner_select.find_all(exp.Window)
118        window_alias_names = {window.parent.alias_or_name for window in window_expressions}
119        inner_select_name = inner_select.parent.alias_or_name
120        unmergable_window_columns = [
121            column
122            for column in outer_scope.columns
123            if column.find_ancestor(
124                exp.Where, exp.Group, exp.Order, exp.Join, exp.Having, exp.AggFunc
125            )
126        ]
127        window_expressions_in_unmergable = [
128            column
129            for column in unmergable_window_columns
130            if column.table == inner_select_name and column.name in window_alias_names
131        ]
132        return any(window_expressions_in_unmergable)
133
134    def _outer_select_joins_on_inner_select_join():
135        """
136        All columns from the inner select in the ON clause must be from the first FROM table.
137
138        That is, this can be merged:
139            SELECT * FROM x JOIN (SELECT y.a AS a FROM y JOIN z) AS q ON x.a = q.a
140                                         ^^^           ^
141        But this can't:
142            SELECT * FROM x JOIN (SELECT z.a AS a FROM y JOIN z) AS q ON x.a = q.a
143                                         ^^^                  ^
144        """
145        if not isinstance(from_or_join, exp.Join):
146            return False
147
148        alias = from_or_join.alias_or_name
149
150        on = from_or_join.args.get("on")
151        if not on:
152            return False
153        selections = [c.name for c in on.find_all(exp.Column) if c.table == alias]
154        inner_from = inner_scope.expression.args.get("from")
155        if not inner_from:
156            return False
157        inner_from_table = inner_from.alias_or_name
158        inner_projections = {s.alias_or_name: s for s in inner_scope.selects}
159        return any(
160            col.table != inner_from_table
161            for selection in selections
162            for col in inner_projections[selection].find_all(exp.Column)
163        )
164
165    return (
166        isinstance(outer_scope.expression, exp.Select)
167        and isinstance(inner_select, exp.Select)
168        and not any(inner_select.args.get(arg) for arg in UNMERGABLE_ARGS)
169        and inner_select.args.get("from")
170        and not outer_scope.pivots
171        and not any(e.find(exp.AggFunc, exp.Select) for e in inner_select.expressions)
172        and not (leave_tables_isolated and len(outer_scope.selected_sources) > 1)
173        and not (
174            isinstance(from_or_join, exp.Join)
175            and inner_select.args.get("where")
176            and from_or_join.side in {"FULL", "LEFT", "RIGHT"}
177        )
178        and not (
179            isinstance(from_or_join, exp.From)
180            and inner_select.args.get("where")
181            and any(
182                j.side in {"FULL", "RIGHT"} for j in outer_scope.expression.args.get("joins", [])
183            )
184        )
185        and not _outer_select_joins_on_inner_select_join()
186        and not _is_a_window_expression_in_unmergable_operation()
187    )
188
189
190def _rename_inner_sources(outer_scope, inner_scope, alias):
191    """
192    Renames any sources in the inner query that conflict with names in the outer query.
193
194    Args:
195        outer_scope (sqlglot.optimizer.scope.Scope)
196        inner_scope (sqlglot.optimizer.scope.Scope)
197        alias (str)
198    """
199    taken = set(outer_scope.selected_sources)
200    conflicts = taken.intersection(set(inner_scope.selected_sources))
201    conflicts -= {alias}
202
203    for conflict in conflicts:
204        new_name = find_new_name(taken, conflict)
205
206        source, _ = inner_scope.selected_sources[conflict]
207        new_alias = exp.to_identifier(new_name)
208
209        if isinstance(source, exp.Subquery):
210            source.set("alias", exp.TableAlias(this=new_alias))
211        elif isinstance(source, exp.Table) and source.alias:
212            source.set("alias", new_alias)
213        elif isinstance(source, exp.Table):
214            source.replace(exp.alias_(source, new_alias))
215
216        for column in inner_scope.source_columns(conflict):
217            column.set("table", exp.to_identifier(new_name))
218
219        inner_scope.rename_source(conflict, new_name)
220
221
222def _merge_from(outer_scope, inner_scope, node_to_replace, alias):
223    """
224    Merge FROM clause of inner query into outer query.
225
226    Args:
227        outer_scope (sqlglot.optimizer.scope.Scope)
228        inner_scope (sqlglot.optimizer.scope.Scope)
229        node_to_replace (exp.Subquery|exp.Table)
230        alias (str)
231    """
232    new_subquery = inner_scope.expression.args["from"].this
233    node_to_replace.replace(new_subquery)
234    for join_hint in outer_scope.join_hints:
235        tables = join_hint.find_all(exp.Table)
236        for table in tables:
237            if table.alias_or_name == node_to_replace.alias_or_name:
238                table.set("this", exp.to_identifier(new_subquery.alias_or_name))
239    outer_scope.remove_source(alias)
240    outer_scope.add_source(
241        new_subquery.alias_or_name, inner_scope.sources[new_subquery.alias_or_name]
242    )
243
244
245def _merge_joins(outer_scope, inner_scope, from_or_join):
246    """
247    Merge JOIN clauses of inner query into outer query.
248
249    Args:
250        outer_scope (sqlglot.optimizer.scope.Scope)
251        inner_scope (sqlglot.optimizer.scope.Scope)
252        from_or_join (exp.From|exp.Join)
253    """
254
255    new_joins = []
256
257    joins = inner_scope.expression.args.get("joins") or []
258    for join in joins:
259        new_joins.append(join)
260        outer_scope.add_source(join.alias_or_name, inner_scope.sources[join.alias_or_name])
261
262    if new_joins:
263        outer_joins = outer_scope.expression.args.get("joins", [])
264
265        # Maintain the join order
266        if isinstance(from_or_join, exp.From):
267            position = 0
268        else:
269            position = outer_joins.index(from_or_join) + 1
270        outer_joins[position:position] = new_joins
271
272        outer_scope.expression.set("joins", outer_joins)
273
274
275def _merge_expressions(outer_scope, inner_scope, alias):
276    """
277    Merge projections of inner query into outer query.
278
279    Args:
280        outer_scope (sqlglot.optimizer.scope.Scope)
281        inner_scope (sqlglot.optimizer.scope.Scope)
282        alias (str)
283    """
284    # Collect all columns that reference the alias of the inner query
285    outer_columns = defaultdict(list)
286    for column in outer_scope.columns:
287        if column.table == alias:
288            outer_columns[column.name].append(column)
289
290    # Replace columns with the projection expression in the inner query
291    for expression in inner_scope.expression.expressions:
292        projection_name = expression.alias_or_name
293        if not projection_name:
294            continue
295        columns_to_replace = outer_columns.get(projection_name, [])
296        for column in columns_to_replace:
297            column.replace(expression.unalias().copy())
298
299
300def _merge_where(outer_scope, inner_scope, from_or_join):
301    """
302    Merge WHERE clause of inner query into outer query.
303
304    Args:
305        outer_scope (sqlglot.optimizer.scope.Scope)
306        inner_scope (sqlglot.optimizer.scope.Scope)
307        from_or_join (exp.From|exp.Join)
308    """
309    where = inner_scope.expression.args.get("where")
310    if not where or not where.this:
311        return
312
313    expression = outer_scope.expression
314
315    if isinstance(from_or_join, exp.Join):
316        # Merge predicates from an outer join to the ON clause
317        # if it only has columns that are already joined
318        from_ = expression.args.get("from")
319        sources = {from_.alias_or_name} if from_ else {}
320
321        for join in expression.args["joins"]:
322            source = join.alias_or_name
323            sources.add(source)
324            if source == from_or_join.alias_or_name:
325                break
326
327        if exp.column_table_names(where.this) <= sources:
328            from_or_join.on(where.this, copy=False)
329            from_or_join.set("on", from_or_join.args.get("on"))
330            return
331
332    expression.where(where.this, copy=False)
333
334
335def _merge_order(outer_scope, inner_scope):
336    """
337    Merge ORDER clause of inner query into outer query.
338
339    Args:
340        outer_scope (sqlglot.optimizer.scope.Scope)
341        inner_scope (sqlglot.optimizer.scope.Scope)
342    """
343    if (
344        any(
345            outer_scope.expression.args.get(arg) for arg in ["group", "distinct", "having", "order"]
346        )
347        or len(outer_scope.selected_sources) != 1
348        or any(expression.find(exp.AggFunc) for expression in outer_scope.expression.expressions)
349    ):
350        return
351
352    outer_scope.expression.set("order", inner_scope.expression.args.get("order"))
353
354
355def _merge_hints(outer_scope, inner_scope):
356    inner_scope_hint = inner_scope.expression.args.get("hint")
357    if not inner_scope_hint:
358        return
359    outer_scope_hint = outer_scope.expression.args.get("hint")
360    if outer_scope_hint:
361        for hint_expression in inner_scope_hint.expressions:
362            outer_scope_hint.append("expressions", hint_expression)
363    else:
364        outer_scope.expression.set("hint", inner_scope_hint)
365
366
367def _pop_cte(inner_scope):
368    """
369    Remove CTE from the AST.
370
371    Args:
372        inner_scope (sqlglot.optimizer.scope.Scope)
373    """
374    cte = inner_scope.expression.parent
375    with_ = cte.parent
376    if len(with_.expressions) == 1:
377        with_.pop()
378    else:
379        cte.pop()
def merge_subqueries(expression, leave_tables_isolated=False):
 9def merge_subqueries(expression, leave_tables_isolated=False):
10    """
11    Rewrite sqlglot AST to merge derived tables into the outer query.
12
13    This also merges CTEs if they are selected from only once.
14
15    Example:
16        >>> import sqlglot
17        >>> expression = sqlglot.parse_one("SELECT a FROM (SELECT x.a FROM x) CROSS JOIN y")
18        >>> merge_subqueries(expression).sql()
19        'SELECT x.a FROM x CROSS JOIN y'
20
21    If `leave_tables_isolated` is True, this will not merge inner queries into outer
22    queries if it would result in multiple table selects in a single query:
23        >>> expression = sqlglot.parse_one("SELECT a FROM (SELECT x.a FROM x) CROSS JOIN y")
24        >>> merge_subqueries(expression, leave_tables_isolated=True).sql()
25        'SELECT a FROM (SELECT x.a FROM x) CROSS JOIN y'
26
27    Inspired by https://dev.mysql.com/doc/refman/8.0/en/derived-table-optimization.html
28
29    Args:
30        expression (sqlglot.Expression): expression to optimize
31        leave_tables_isolated (bool):
32    Returns:
33        sqlglot.Expression: optimized expression
34    """
35    expression = merge_ctes(expression, leave_tables_isolated)
36    expression = merge_derived_tables(expression, leave_tables_isolated)
37    return expression

Rewrite sqlglot AST to merge derived tables into the outer query.

This also merges CTEs if they are selected from only once.

Example:
>>> import sqlglot
>>> expression = sqlglot.parse_one("SELECT a FROM (SELECT x.a FROM x) CROSS JOIN y")
>>> merge_subqueries(expression).sql()
'SELECT x.a FROM x CROSS JOIN y'

If leave_tables_isolated is True, this will not merge inner queries into outer queries if it would result in multiple table selects in a single query:

expression = sqlglot.parse_one("SELECT a FROM (SELECT x.a FROM x) CROSS JOIN y") merge_subqueries(expression, leave_tables_isolated=True).sql() 'SELECT a FROM (SELECT x.a FROM x) CROSS JOIN y'

Inspired by https://dev.mysql.com/doc/refman/8.0/en/derived-table-optimization.html

Arguments:
  • expression (sqlglot.Expression): expression to optimize
  • leave_tables_isolated (bool):
Returns:

sqlglot.Expression: optimized expression

UNMERGABLE_ARGS = {'match', 'sample', 'having', 'settings', 'into', 'offset', 'group', 'pivots', 'with', 'laterals', 'kind', 'locks', 'distinct', 'cluster', 'format', 'limit', 'sort', 'windows', 'distribute', 'qualify'}
def merge_ctes(expression, leave_tables_isolated=False):
51def merge_ctes(expression, leave_tables_isolated=False):
52    scopes = traverse_scope(expression)
53
54    # All places where we select from CTEs.
55    # We key on the CTE scope so we can detect CTES that are selected from multiple times.
56    cte_selections = defaultdict(list)
57    for outer_scope in scopes:
58        for table, inner_scope in outer_scope.selected_sources.values():
59            if isinstance(inner_scope, Scope) and inner_scope.is_cte:
60                cte_selections[id(inner_scope)].append(
61                    (
62                        outer_scope,
63                        inner_scope,
64                        table,
65                    )
66                )
67
68    singular_cte_selections = [v[0] for k, v in cte_selections.items() if len(v) == 1]
69    for outer_scope, inner_scope, table in singular_cte_selections:
70        from_or_join = table.find_ancestor(exp.From, exp.Join)
71        if _mergeable(outer_scope, inner_scope, leave_tables_isolated, from_or_join):
72            alias = table.alias_or_name
73            _rename_inner_sources(outer_scope, inner_scope, alias)
74            _merge_from(outer_scope, inner_scope, table, alias)
75            _merge_expressions(outer_scope, inner_scope, alias)
76            _merge_joins(outer_scope, inner_scope, from_or_join)
77            _merge_where(outer_scope, inner_scope, from_or_join)
78            _merge_order(outer_scope, inner_scope)
79            _merge_hints(outer_scope, inner_scope)
80            _pop_cte(inner_scope)
81            outer_scope.clear_cache()
82    return expression
def merge_derived_tables(expression, leave_tables_isolated=False):
 85def merge_derived_tables(expression, leave_tables_isolated=False):
 86    for outer_scope in traverse_scope(expression):
 87        for subquery in outer_scope.derived_tables:
 88            from_or_join = subquery.find_ancestor(exp.From, exp.Join)
 89            alias = subquery.alias_or_name
 90            inner_scope = outer_scope.sources[alias]
 91            if _mergeable(outer_scope, inner_scope, leave_tables_isolated, from_or_join):
 92                _rename_inner_sources(outer_scope, inner_scope, alias)
 93                _merge_from(outer_scope, inner_scope, subquery, alias)
 94                _merge_expressions(outer_scope, inner_scope, alias)
 95                _merge_joins(outer_scope, inner_scope, from_or_join)
 96                _merge_where(outer_scope, inner_scope, from_or_join)
 97                _merge_order(outer_scope, inner_scope)
 98                _merge_hints(outer_scope, inner_scope)
 99                outer_scope.clear_cache()
100    return expression