INF: How to Restrict the Inner Table of an ANSI Outer JoinID: Q176480
|
SQL Server 6.5 supports the ANSI-style join syntax for cross, inner, and outer joins. Restricting the inner table of an ANSI-style outer join may appear to return results that differ from those returned using the Transact- SQL-style outer join syntax. This article discusses the situation in which an ANSI-style outer join appears to return results different from the Transact-SQL-style outer join syntax, and demonstrates the correct syntax to use for an ANSI-style outer join.
An outer join allows you to restrict the rows in one table, while not
restricting the rows in another table. Consider the following Transact-SQL-
style example, using the pubs database:
SELECT titles.title_id, title, qty
FROM titles, sales
WHERE titles.title_id *= sales.title_id
SELECT titles.title_id, title, qty
FROM titles LEFT OUTER JOIN sales
ON titles.title_id = sales.title_id
SELECT titles.title_id, title, qty
FROM titles, sales
WHERE titles.title_id *= sales.title_id
AND stor_id = '7066'
SELECT titles.title_id, title, qty
FROM titles LEFT OUTER JOIN sales
ON titles.title_id = sales.title_id
WHERE stor_id = '7066'
SELECT titles.title_id, title, qty
FROM titles LEFT OUTER JOIN sales
ON titles.title_id = sales.title_id
AND stor_id = '7066'
Additional query words:
outerjoin right outer join tsql t-sql tran-sql transql
transsql trans-sql
Keywords : kbusage SSrvISQL SSrvTran_SQL
Version : WINNT:6.5
Platform : WINDOWS
Issue type : kbhowto
Last Reviewed: April 21, 1999