MySQL :: MySQL 5.7 Reference Manual :: 13.2.10.12 Restrictions on Subqueries (original) (raw)

13.2.10.12 Restrictions on Subqueries

DELETE FROM t WHERE ... (SELECT ... FROM t ...);  
UPDATE t ... WHERE col = (SELECT ... FROM t ...);  
{INSERT|REPLACE} INTO t (SELECT ... FROM t ...);  

Exception: The preceding prohibition does not apply if for the modified table you are using a derived table and that derived table is materialized rather than merged into the outer query. (SeeSection 8.2.2.4, “Optimizing Derived Tables and View References with Merging or Materialization”.) Example:

UPDATE t ... WHERE col = (SELECT * FROM (SELECT ... FROM t...) AS dt ...);  

Here the result from the derived table is materialized as a temporary table, so the relevant rows int have already been selected by the time the update to t takes place.

(expr_1, ..., expr_n) [NOT] IN table_subquery  

But this is not supported:

(expr_1, ..., expr_n) op {ALL|ANY|SOME} subquery  

The reason for supporting row comparisons forIN but not for the others is thatIN is implemented by rewriting it as a sequence of = comparisons and AND operations. This approach cannot be used for ALL,ANY, or SOME.

mysql> SELECT * FROM t1  
       WHERE s1 IN (SELECT s2 FROM t2 ORDER BY s1 LIMIT 1);  
ERROR 1235 (42000): This version of MySQL does not yet support  
 'LIMIT & IN/ALL/ANY/SOME subquery'  
SELECT ... WHERE x IN (SELECT f() ...);  

This behavior is an extension to the SQL standard. In MySQL, it can produce nondeterministic results becausef() might be executed a different number of times for different executions of a given query depending on how the optimizer chooses to handle it.
For statement-based or mixed-format replication, one implication of this indeterminism is that such a query can produce different results on the source and its replicas.