Compartilhar via


EXISTS (Transact-SQL)

Aplica-se a:SQL ServerBanco de Dados SQL do AzureInstância Gerenciada de SQL do AzureAzure Synapse AnalyticsAnalytics Platform System (PDW)Ponto de extremidade de análise de SQL no Microsoft FabricWarehouse no Microsoft FabricBanco de Dados SQL no Microsoft Fabric

Especifica uma subconsulta a ser testada quanto à existência de linhas.

Convenções de sintaxe de Transact-SQL

Sintaxe

EXISTS ( subquery )

Argumentos

subconsulta

Uma instrução restrita SELECT . A INTO palavra-chave não é permitida. Para obter mais informações, consulte as informações sobre subconsultas em SELECT.

Tipos de retorno

Booliano

Valores de resultado

Retorna TRUE se uma subconsulta contiver linhas.

Exemplos

Os exemplos de código neste artigo usam o banco de dados de exemplo AdventureWorks2022 ou AdventureWorksDW2022, que você pode baixar na página inicial Microsoft SQL Server Samples and Community Projects.

a. Usar NULL em uma subconsulta para ainda retornar um conjunto de resultados

O exemplo a NULL seguir retorna um conjunto de resultados com TRUE especificado na subconsulta e ainda é avaliado usando EXISTS.

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

B. Comparar consultas usando EXISTS e IN

O exemplo a seguir compara duas consultas semanticamente equivalentes. A primeira consulta usa EXISTS e a segunda usa IN.

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

A consulta a seguir usa IN.

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

Este é o conjunto de resultados para qualquer consulta.

FirstName                                          LastName
-------------------------------------------------- ----------
Barry                                              Johnson
David                                              Johnson
Willis                                             Johnson

C. Comparar consultas usando EXISTS e = ANY

O exemplo a seguir mostra duas consultas para localizar lojas cujo nome seja igual ao de um fornecedor. A primeira consulta usa EXISTS e a segunda usa = ANY.

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

A consulta a seguir usa = ANY.

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

D. Comparar consultas usando EXISTS e IN

O exemplo a seguir mostra consultas para localizar os funcionários de departamentos que começam com P.

SELECT p.FirstName,
       p.LastName,
       e.JobTitle
FROM Person.Person AS p
     INNER JOIN HumanResources.Employee AS e
         ON e.BusinessEntityID = p.BusinessEntityID
WHERE EXISTS (SELECT *
      FROM HumanResources.Department AS d
            INNER JOIN HumanResources.EmployeeDepartmentHistory AS edh
               ON d.DepartmentID = edh.DepartmentID
      WHERE e.BusinessEntityID = edh.BusinessEntityID
            AND d.Name LIKE 'P%');
GO

A consulta a seguir usa IN.

SELECT p.FirstName,
       p.LastName,
       e.JobTitle
FROM Person.Person AS p
     INNER JOIN HumanResources.Employee AS e
         ON e.BusinessEntityID = p.BusinessEntityID
     INNER 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. Usar NÃO EXISTE

NOT EXISTS funciona o oposto de EXISTS. A WHERE cláusula in NOT EXISTS será atendida se nenhuma linha for retornada pela subconsulta. O exemplo a seguir localiza funcionários que não estão em departamentos que têm nomes que começam com P.

SELECT p.FirstName,
       p.LastName,
       e.JobTitle
FROM Person.Person AS p
     INNER JOIN HumanResources.Employee AS e
         ON e.BusinessEntityID = p.BusinessEntityID
WHERE NOT EXISTS (SELECT *
      FROM HumanResources.Department AS d
            INNER 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

Veja a seguir o conjunto de resultados.

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

Exemplos: Azure Synapse Analytics e PDW (Analytics Platform System)

F. Usar EXISTS

O exemplo a seguir identifica se uma linha na tabela ProspectiveBuyer pode corresponder a linhas na tabela DimCustomer. A consulta retorna linhas somente quando os valores e LastName os BirthDate valores nas duas tabelas correspondem.

SELECT a.LastName, a.BirthDate
FROM DimCustomer AS a
WHERE EXISTS (SELECT *
      FROM dbo.ProspectiveBuyer AS b
      WHERE (a.LastName = b.LastName)
            AND (a.BirthDate = b.BirthDate));

G. Usar NÃO EXISTE

NOT EXISTS funciona como o oposto como EXISTS. A WHERE cláusula in NOT EXISTS será atendida se nenhuma linha for retornada pela subconsulta. O exemplo a DimCustomer seguir localiza linhas na tabela em que a LastNameBirthDate tabela não corresponde a nenhuma entrada na ProspectiveBuyers tabela.

SELECT a.LastName,
       a.BirthDate
FROM DimCustomer AS a
WHERE NOT EXISTS (SELECT *
      FROM dbo.ProspectiveBuyer AS b
      WHERE (a.LastName = b.LastName)
            AND (a.BirthDate = b.BirthDate));