MySQL executes joins between tables using a nested-loop algorithm or variations on it.
Nested-Loop Join Algorithm
A simple nested-loop join (NLJ) algorithm reads rows from the first table in a loop one at a time, passing each row to a nested loop that processes the next table in the join. This process is repeated as many times as there remain tables to be joined.
Assume that a join between three tables t1
,
t2
, and t3
is to be
executed using the following join types:
Table Join Type t1 range t2 ref t3 ALL
If a simple NLJ algorithm is used, the join would be processed like this:
for each row in t1 matching range { for each row in t2 matching reference key { for each row in t3 { if row satisfies join conditions, send to client } } }
Because the NLJ algorithm passes rows one at a time from outer loops to inner loops, tables processed in the inner loops typically are read many times.
Block Nested-Loop Join Algorithm
A Block Nested-Loop (BNL) Join algorithm uses buffering of rows read in outer loops to reduce the number of times that tables in inner loops must be read. For example, if 10 rows are read into a buffer and the buffer is passed to the next inner loop, each row read in the inner loop can be compared against all 10 rows in the buffer. The reduces the number of times the inner table must be read by an order of magnitude.
MySQL uses join buffering under these conditions:
The
join_buffer_size
system variable determines the size of each join buffer.Join buffering can be used when the join is of type
ALL
orindex
(in other words, when no possible keys can be used, and a full scan is done, of either the data or index rows, respectively), orrange
.One buffer is allocated for each join that can be buffered, so a given query might be processed using multiple join buffers.
A join buffer is never allocated for the first nonconst table, even if it would be of type
ALL
orindex
.A join buffer is allocated prior to executing the join and freed after the query is done.
Only columns of interest to the join are stored in the join buffer, not whole rows.
For the example join described previously for the NLJ algorithm (without buffering), the join would be done as follow using join buffering:
for each row in t1 matching range { for each row in t2 matching reference key { store used columns from t1, t2 in join buffer if buffer is full { for each row in t3 { for each t1, t2 combination in join buffer { if row satisfies join conditions, send to client } } empty buffer } } } if buffer is not empty { for each row in t3 { for each t1, t2 combination in join buffer { if row satisfies join conditions, send to client } } }
If S
is the size of each stored
t1
, t2
combination is the
join buffer and C
is the number of
combinations in the buffer, the number of times table
t3
is scanned is:
(S
*C
)/join_buffer_size + 1
One implication is that the number of t3
scans decreases as the value of
join_buffer_size
increases, up
to the point when
join_buffer_size
is large
enough to hold all previous row combinations. At that point,
there is no speed to be gained by making it larger.