EXISTS (Transact-SQL)

Specifies a subquery to test for the existence of rows.

Topic link iconTransact-SQL Syntax Conventions

Syntax

EXISTS subquery

Arguments

  • subquery
    Is a restricted SELECT statement. The COMPUTE clause, and the INTO keyword are not allowed. For more information, see the information about subqueries in SELECT (Transact-SQL).

Result Types

Boolean

Result Values

Returns TRUE if a subquery contains any rows.

Examples

A. Using NULL in a subquery to still return a result set

The following example returns a result set with NULL specified in the subquery and still evaluates to TRUE by using EXISTS.

USE AdventureWorks ;
GO
SELECT DepartmentID, Name 
FROM HumanResources.Department 
WHERE EXISTS (SELECT NULL)
ORDER BY Name ASC ;

B. Comparing queries by using EXISTS and IN

The following example compares two queries that are semantically equivalent. The first query uses EXISTS and the second query uses IN.

USE AdventureWorks ;
GO
SELECT a.FirstName, a.LastName
FROM Person.Contact AS a
WHERE EXISTS
(SELECT * 
 FROM HumanResources.Employee AS b
 WHERE a.ContactId = b.ContactID
 AND a.LastName = 'Johnson');
GO

The following query uses IN.

USE AdventureWorks ;
GO
SELECT a.FirstName, a.LastName
FROM Person.Contact AS a
WHERE a.LastName IN
(SELECT a.LastName
 FROM HumanResources.Employee AS b
 WHERE a.ContactId = b.ContactID
 AND a.LastName = 'Johnson');
GO

Here is the result set for either query.

FirstName                                          LastName
-------------------------------------------------- ----------
Barry                                              Johnson
David                                              Johnson
Willis                                             Johnson
(3 row(s) affected)

C. Comparing queries by using EXISTS and = ANY

The following example shows two queries to find stores whose name is the same name as a vendor. The first query uses EXISTS and the second uses =``ANY.

USE AdventureWorks ;
GO
SELECT DISTINCT s.Name
FROM Sales.Store s 
WHERE EXISTS
(SELECT *
FROM Purchasing.Vendor v
WHERE s.Name = v.Name) ;
GO

The following query uses = ANY.

USE AdventureWorks ;
GO
SELECT DISTINCT s.Name
FROM Sales.Store s 
WHERE s.Name = ANY
(SELECT v.Name
FROM Purchasing.Vendor v ) ;
GO

D. Comparing queries by using EXISTS and IN

The following example shows queries to find employees of departments that start with P.

USE AdventureWorks;
GO
SELECT c.FirstName, c.LastName, e.Title
FROM Person.Contact c JOIN HumanResources.Employee e
ON e.ContactID = c.ContactID WHERE EXISTS
(SELECT *
FROM HumanResources.Department d
WHERE e.DepartmentID = d.DepartmentID
AND d.Name LIKE 'P%');
GO

The following query uses IN.

USE AdventureWorks;
GO
SELECT c.FirstName, c.LastName, e.Title
FROM Person.Contact c JOIN HumanResources.Employee e
ON e.ContactID = c.ContactID WHERE DepartmentID IN
(SELECT DepartmentID
FROM HumanResources.Department
WHERE Name LIKE 'P%');
GO

E. Using NOT EXISTS

NOT EXISTS works the opposite as EXISTS. The WHERE clause in NOT EXISTS is satisfied if no rows are returned by the subquery. The following example finds employees who are not in departments and have names that start with P.

USE AdventureWorks;
GO
SELECT c.FirstName, c.LastName, e.Title
FROM Person.Contact c JOIN HumanResources.Employee e
ON e.ContactID = c.ContactID WHERE NOT EXISTS
(SELECT *
FROM HumanResources.Department d
WHERE e.DepartmentID = d.DepartmentID
AND d.Name LIKE 'P%')
ORDER BY LastName, FirstName
GO

Here is the result set.

FirstName                      LastName                       Title                         
------------------------------ ------------------------------ ------------
Syed                           Abbas                          Pacific Sales Manager         
Hazem                          Abolrous                       Quality Assurance Manager     
Humberto                       Acevedo                        Application Specialist        
Pilar                          Ackerman                       Shipping & Receiving Superviso
François                       Ajenstat                       Database Administrator        
Amy                            Alberts                        European Sales Manager        
Sean                           Alexander                      Quality Assurance Technician  
Pamela                         Ansman-Wolfe                   Sales Representative          
Zainal                         Arifin                         Document Control Manager      
David                          Barber                         Assistant to CFO              
Paula                          Barreto de Mattos              Human Resources Manager       
Shai                           Bassli                         Facilities Manager            
Wanida                         Benshoof                       Marketing Assistant           
Karen                          Berg                           Application Specialist        
Karen                          Berge                          Document Control Assistant    
Andreas                        Berglund                       Quality Assurance Technician  
Matthias                       Berndt                         Shipping & Receiving Clerk    
Jo                             Berry                          Janitor                       
Jimmy                          Bischoff                       Stocker                       
Michael                        Blythe                         Sales Representative          
David                          Bradley                        Marketing Manager             
Kevin                          Brown                          Marketing Assistant           
David                          Campbell                       Sales Representative          
Jason                          Carlson                        Information Services Manager  
Fernando                       Caro                           Sales Representative          
Sean                           Chai                           Document Control Assistant    
Sootha                         Charncherngkha                 Quality Assurance Technician  
Hao                            Chen                           HR Administrative Assistant   
Kevin                          Chrisulis                      Network Administrator         
Pat                            Coleman                        Janitor                       
Stephanie                      Conroy                         Network Manager               
Debra                          Core                           Application Specialist        
Ovidiu                         Crãcium                        Sr. Tool Designer             
Grant                          Culbertson                     HR Administrative Assistant   
Mary                           Dempsey                        Marketing Assistant
Thierry                        D'Hers                         Tool Designer                 
Terri                          Duffy                          VP Engineering                
Susan                          Eaton                          Stocker                       
Terry                          Eminhizer                      Marketing Specialist          
Gail                           Erickson                       Design Engineer               
Janice                         Galvin                         Tool Designer                 
Mary                           Gibson                         Marketing Specialist          
Jossef                         Goldberg                       Design Engineer               
Sariya                         Harnpadoungsataya              Marketing Specialist          
Mark                           Harrington                     Quality Assurance Technician  
Magnus                         Hedlund                        Facilities Assistant          
Shu                            Ito                            Sales Representative          
Stephen                        Jiang                          North American Sales Manager  
Willis                         Johnson                        Recruiter                     
Brannon                        Jones                          Finance Manager               
Tengiz                         Kharatishvili                  Control Specialist            
Christian                      Kleinerman                     Maintenance Supervisor        
Vamsi                          Kuppa                          Shipping & Receiving Clerk    
David                          Liu                            Accounts Manager              
Vidur                          Luthra                         Recruiter                     
Stuart                         Macrae                         Janitor                       
Diane                          Margheim                       Research & Development Enginee
Mindy                          Martin                         Benefits Specialist           
Gigi                           Matthew                        Research & Development Enginee
Tete                           Mensa-Annan                    Sales Representative          
Ramesh                         Meyyappan                      Application Specialist        
Dylan                          Miller                         Research & Development Manager
Linda                          Mitchell                       Sales Representative          
Barbara                        Moreland                       Accountant                    
Laura                          Norman                         Chief Financial Officer       
Chris                          Norred                         Control Specialist            
Jae                            Pak                            Sales Representative          
Wanda                          Parks                          Janitor                       
Deborah                        Poe                            Accounts Receivable Specialist
Kim                            Ralls                          Stocker                       
Tsvi                           Reiter                         Sales Representative          
Sharon                         Salavaria                      Design Engineer               
Ken                            Sanchez                        Chief Executive Officer       
José                           Saraiva                        Sales Representative          
Mike                           Seamans                        Accountant                    
Ashvini                        Sharma                         Network Administrator         
Janet                          Sheperdigian                   Accounts Payable Specialist   
Candy                          Spoon                          Accounts Receivable Specialist
Michael                        Sullivan                       Sr. Design Engineer           
Dragan                         Tomic                          Accounts Payable Specialist   
Lynn                           Tsoflias                       Sales Representative          
Rachel                         Valdez                         Sales Representative          
Garrett                        Vargar                         Sales Representative          
Ranjit                         Varkey Chudukatil              Sales Representative          
Bryan                          Walton                         Accounts Receivable Specialist
Jian Shuo                      Wang                           Engineering Manager           
Brian                          Welcker                        VP Sales                      
Jill                           Williams                       Marketing Specialist          
Dan                            Wilson                         Database Administrator        
John                           Wood                           Marketing Specialist          
Peng                           Wu                             Quality Assurance Supervisor  
(91 row(s) affected)

See Also

Reference

Expressions (Transact-SQL)
Functions (Transact-SQL)
WHERE (Transact-SQL)

Help and Information

Getting SQL Server 2005 Assistance