INF: Comparison of Join TechniquesID: Q197297
|
Microsoft SQL Server version 7.0 includes some new join techniques, such as the hash join and sort-merge join, to supplement nested-loop joins. This article describes these new techniques and compares and contrasts them.
Microsoft SQL Server version 6.5 and earlier had only one technique for
joining records: the nested loops join. SQL Server 7.0 implements hash and
sort-based algorithms. The decision by the query engine on whether to use
hash versus sort depends on relative sizes of the inputs, whether they are
sorted or not, whether the hash table will fit entirely in memory, and so
on. The optimizer will always choose the best join plan to execute your
query, and that may be any one of the three options. The difference between
hash joins and merge joins is often small, but there are certain situations
where one is better than the other. There are considerable differences
between these two join types and the nested loops join, as shown below. The
example in this article is provided only as an illustration. The table at
the end of this article is an illustration of some decisions that may
affect the join type used. It is generally recommended that you not force
join types, overriding the optimizer.
SELECT * FROM reserves AS r1 JOIN sailors AS s1 ON r1.sid=s1.sid option
(loop join)
|--Nested Loops(Inner Join)
|--Sort(ORDER BY:([r1].[sid] ASC))
| |--Table Scan(OBJECT:([Northwind].[dbo].[reserves] AS [r1]))
|--Clustered Index Seek(OBJECT:([Northwind].[dbo].[sailors].[I2] AS
[s1]), SEEK:([s1].[sid]=[r1].[sid]) ORDERED)
|--Hash Match(Inner Join, HASH:([s1].[sid])=([r1].[sid]),
RESIDUAL:([s1].[sid]=[r1].[sid]))
|--Clustered Index Scan(OBJECT:([Northwind].[dbo].[sailors].[I2] AS [s1]))
|--Table Scan(OBJECT:([Northwind].[dbo].[reserves] AS [r1]))
Table 'reserves'. Scan count 1, logical reads 529, physical reads 0, read-
ahead reads 0.
|--Merge Join(Inner Join, MANY-TO-MANY MERGE:([r1].[sid])=([s1].[sid]),
RESIDUAL:([s1].[sid]=[r1].[sid]))
|--Sort(ORDER BY:([r1].[sid] ASC))
| |--Table Scan(OBJECT:([Northwind].[dbo].[reserves] AS [r1]))
|--Clustered Index Scan(OBJECT:([Northwind].[dbo].[sailors].[I2] AS s1]), ORDERED)
CPU time = 1081 ms, elapsed time = 2211 ms.
CPU time = 181 ms, elapsed time = 479 ms.
==========================================================================
Property | Nested loop | Hash or merge
=========================|=============================================
Only limited memory | Better |Worse,
|memory is needed for sorting
|or building hash table
Need first row fast | Better |Worse,
|need to sort or hash
|before a row is returned
Selecting only a few | Better |Worse
rows from inner table | |
Parallelism |Works best |Will work
Index available on inner |Works best |Will work
Without one equality |Works |Needs at least 1 equality
2 Very large inputs |Worse |Not much better,
|hash and sort will have
|almost equal cost
One very small |Worse |Hash better than merge
and large input | |
Additional query words: prodsql Comparison optimizer
Keywords :
Version : WINNT:7.0
Platform : winnt
Issue type : kbinfo
Last Reviewed: April 19, 1999