EXISTS (Transact-SQL)
指定一个子查询,测试行是否存在。
语法
EXISTS subquery
参数
- subquery
受限制的 SELECT 语句。 不允许使用 INTO 关键字。 有关详细信息,请参阅 SELECT (Transact-SQL) 中有关子查询的信息。
结果类型
Boolean
结果值
如果子查询包含任何行,则返回 TRUE。
示例
A.在子查询中使用 NULL 仍然返回结果集
以下示例返回在子查询中指定了 NULL 时的结果集,并且通过使用 EXISTS 仍然求值为 TRUE。
USE AdventureWorks2012 ;
GO
SELECT DepartmentID, Name
FROM HumanResources.Department
WHERE EXISTS (SELECT NULL)
ORDER BY Name ASC ;
B.比较使用 EXISTS 和 IN 的查询
以下示例比较了两个语义等同的查询。 第一个查询使用 EXISTS,第二个查询使用 IN。
USE AdventureWorks2012 ;
GO
SELECT a.FirstName, a.LastName
FROM Person.Person AS a
WHERE EXISTS
(SELECT *
FROM HumanResources.Employee AS b
WHERE a.BusinessEntityID = b.BusinessEntityID
AND a.LastName = 'Johnson');
GO
下面的查询使用 IN。
USE AdventureWorks2012 ;
GO
SELECT a.FirstName, a.LastName
FROM Person.Person AS a
WHERE a.LastName IN
(SELECT a.LastName
FROM HumanResources.Employee AS b
WHERE a.BusinessEntityID = b.BusinessEntityID
AND a.LastName = 'Johnson');
GO
以下是其中任一查询的结果集。
FirstName LastName
-------------------------------------------------- ----------
Barry Johnson
David Johnson
Willis Johnson
(3 row(s) affected)
C.比较使用 EXISTS 和 = ANY 的查询
以下示例显示两个查找其名称与供应商名称相同的商店的查询。 第一个查询使用 EXISTS,第二个查询使用 = ANY。
USE AdventureWorks2012 ;
GO
SELECT DISTINCT s.Name
FROM Sales.Store AS s
WHERE EXISTS
(SELECT *
FROM Purchasing.Vendor AS v
WHERE s.Name = v.Name) ;
GO
下面的查询使用 = ANY。
USE AdventureWorks2012 ;
GO
SELECT DISTINCT s.Name
FROM Sales.Store AS s
WHERE s.Name = ANY
(SELECT v.Name
FROM Purchasing.Vendor AS v ) ;
GO
D.比较使用 EXISTS 和 IN 的查询
以下示例显示查找以 P 开头的部门员工的查询。
USE AdventureWorks2012;
GO
SELECT p.FirstName, p.LastName, e.JobTitle
FROM Person.Person AS p
JOIN HumanResources.Employee AS e
ON e.BusinessEntityID = p.BusinessEntityID
WHERE EXISTS
(SELECT *
FROM HumanResources.Department AS d
JOIN HumanResources.EmployeeDepartmentHistory AS edh
ON d.DepartmentID = edh.DepartmentID
WHERE e.BusinessEntityID = edh.BusinessEntityID
AND d.Name LIKE 'P%');
GO
下面的查询使用 IN。
USE AdventureWorks2012;
GO
SELECT p.FirstName, p.LastName, e.JobTitle
FROM Person.Person AS p JOIN HumanResources.Employee AS e
ON e.BusinessEntityID = p.BusinessEntityID
JOIN HumanResources.EmployeeDepartmentHistory AS edh
ON e.BusinessEntityID = edh.BusinessEntityID
WHERE edh.DepartmentID IN
(SELECT DepartmentID
FROM HumanResources.Department
WHERE Name LIKE 'P%');
GO
E.使用 NOT EXISTS
NOT EXISTS 的作用与 EXISTS 正相反。 如果子查询没有返回行,则满足 NOT EXISTS 中的 WHERE 子句。 以下示例查找不在部门中且姓名以 P 开头的员工。
SELECT p.FirstName, p.LastName, e.JobTitle
FROM Person.Person AS p
JOIN HumanResources.Employee AS e
ON e.BusinessEntityID = p.BusinessEntityID
WHERE NOT EXISTS
(SELECT *
FROM HumanResources.Department AS d
JOIN HumanResources.EmployeeDepartmentHistory AS edh
ON d.DepartmentID = edh.DepartmentID
WHERE e.BusinessEntityID = edh.BusinessEntityID
AND d.Name LIKE 'P%')
ORDER BY LastName, FirstName
GO
下面是结果集:
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)