MySQL :: MySQL 8.4 Reference Manual :: 10.2.1.9 Outer Join Optimization (original) (raw)

10.2.1.9 Outer Join Optimization

Outer joins include LEFT JOIN andRIGHT JOIN.

MySQL implements an _`A`_ LEFT JOIN _`B`_ _`joinspecification`_ as follows:

The RIGHT JOIN implementation is analogous to that of LEFT JOIN with the table roles reversed. Right joins are converted to equivalent left joins, as described in Section 10.2.1.10, “Outer Join Simplification”.

For a LEFT JOIN, if theWHERE condition is always false for the generated NULL row, the LEFT JOIN is changed to an inner join. For example, theWHERE clause would be false in the following query if t2.column1 wereNULL:

SELECT * FROM t1 LEFT JOIN t2 ON (column1) WHERE t2.column2=5;

Therefore, it is safe to convert the query to an inner join:

SELECT * FROM t1, t2 WHERE t2.column2=5 AND t1.column1=t2.column1;

Trivial WHERE conditions arising from constant literal expressions are removed during preparation, rather than at a later stage in optimization, by which time joins have already been simplified. Earlier removal of trivial conditions allows the optimizer to convert outer joins to inner joins; this can result in improved plans for queries with outer joins containing trivial conditions in theWHERE clause, such as this one:

SELECT * FROM t1 LEFT JOIN t2 ON condition_1 WHERE condition_2 OR 0 = 1

The optimizer now sees during preparation that 0 = 1 is always false, making OR 0 = 1 redundant, and removes it, leaving this:

SELECT * FROM t1 LEFT JOIN t2 ON condition_1 where condition_2

Now the optimizer can rewrite the query as an inner join, like this:

SELECT * FROM t1 JOIN t2 WHERE condition_1 AND condition_2

Now the optimizer can use table t2 before table t1 if doing so would result in a better query plan. To provide a hint about the table join order, use optimizer hints; seeSection 10.9.3, “Optimizer Hints”. Alternatively, useSTRAIGHT_JOIN; seeSection 15.2.13, “SELECT Statement”. However,STRAIGHT_JOIN may prevent indexes from being used because it disables semijoin transformations; seeOptimizing IN and EXISTS Subquery Predicates with Semijoin Transformations.