The optimizer uses materialization to enable more efficient subquery processing. Materialization speeds up query execution by generating a subquery result as a temporary table, normally in memory. The first time MySQL needs the subquery result, it materializes that result into a temporary table. Any subsequent time the result is needed, MySQL refers again to the temporary table. The optimizer may index the table with a hash index to make lookups fast and inexpensive. The index contains unique values to eliminate duplicates and make the table smaller.
Subquery materialization uses an in-memory temporary table when possible, falling back to on-disk storage if the table becomes too large. See Section 10.4.4, “Internal Temporary Table Use in MySQL”.
          If materialization is not used, the optimizer sometimes
          rewrites a noncorrelated subquery as a correlated subquery.
          For example, the following IN subquery is
          noncorrelated (where_condition
          involves only columns from t2 and not
          t1):
        
SELECT * FROM t1
WHERE t1.a IN (SELECT t2.b FROM t2 WHERE where_condition);
          The optimizer might rewrite this as an
          EXISTS correlated subquery:
        
SELECT * FROM t1
WHERE EXISTS (SELECT t2.b FROM t2 WHERE where_condition AND t1.a=t2.b);Subquery materialization using a temporary table avoids such rewrites and makes it possible to execute the subquery only once rather than once per row of the outer query.
          For subquery materialization to be used in MySQL, the
          optimizer_switch system
          variable materialization
          flag must be enabled. (See
          Section 10.9.2, “Switchable Optimizations”.) With the
          materialization flag
          enabled, materialization applies to subquery predicates that
          appear anywhere (in the select list, WHERE,
          ON, GROUP BY,
          HAVING, or ORDER BY),
          for predicates that fall into any of these use cases:
The predicate has this form, when no outer expression
oe_ior inner expressionie_iis nullable.Nis 1 or larger.(oe_1, oe_2, ..., oe_N) [NOT] IN (SELECT ie_1, i_2, ..., ie_N ...)The predicate has this form, when there is a single outer expression
oeand inner expressionie. The expressions can be nullable.oe [NOT] IN (SELECT ie ...)The predicate is
INorNOT INand a result ofUNKNOWN(NULL) has the same meaning as a result ofFALSE.
          The following examples illustrate how the requirement for
          equivalence of UNKNOWN and
          FALSE predicate evaluation affects whether
          subquery materialization can be used. Assume that
          where_condition involves columns
          only from t2 and not t1
          so that the subquery is noncorrelated.
        
This query is subject to materialization:
SELECT * FROM t1
WHERE t1.a IN (SELECT t2.b FROM t2 WHERE where_condition);
          Here, it does not matter whether the IN
          predicate returns UNKNOWN or
          FALSE. Either way, the row from
          t1 is not included in the query result.
        
          An example where subquery materialization is not used is the
          following query, where t2.b is a nullable
          column:
        
SELECT * FROM t1
WHERE (t1.a,t1.b) NOT IN (SELECT t2.a,t2.b FROM t2
                          WHERE where_condition);The following restrictions apply to the use of subquery materialization:
The types of the inner and outer expressions must match. For example, the optimizer might be able to use materialization if both expressions are integer or both are decimal, but cannot if one expression is integer and the other is decimal.
The inner expression cannot be a
BLOB.
          Use of EXPLAIN with a query
          provides some indication of whether the optimizer uses
          subquery materialization:
Compared to query execution that does not use materialization,
select_typemay change fromDEPENDENT SUBQUERYtoSUBQUERY. This indicates that, for a subquery that would be executed once per outer row, materialization enables the subquery to be executed just once.For extended
EXPLAINoutput, the text displayed by a followingSHOW WARNINGSincludesmaterializeandmaterialized-subquery.
          MySQL can also apply subquery materialization to a
          single-table UPDATE or
          DELETE statement that uses a
          [NOT] IN or [NOT] EXISTS
          subquery predicate, provided that the statement does not use
          ORDER BY or LIMIT, and
          that subquery materialization is allowed by an optimizer hint
          or by the optimizer_switch
          setting.