AdventureWorks
dbo.uspGetEmployeeManagers Stored Procedure
Description
Stored procedure using a recursive query to return the direct and indirect managers of the specified employee.
Properties
Creation Date08/01/2010 08:41
Encrypted
Ansi Nulls
Parameters
ParameterDirectionDescriptionData TypeSize
@EmployeeIDInInput parameter for the stored procedure uspGetEmployeeManagers. Enter a valid EmployeeID from the HumanResources.Employee table.int4
@RETURN_VALUEReturn Value int4
Objects that dbo.uspGetEmployeeManagers depends on
 Database ObjectObject TypeDescriptionDep Level
Person.Contact tablePerson.ContactTableNames of each employee, customer contact, and vendor contact.1
HumanResources.Employee tableHumanResources.EmployeeTableEmployee information such as salary, department, and title.1
dbo.Flag datatypedbo.FlagUser Defined Data Type 2
dbo.Name datatypedbo.NameUser Defined Data Type 2
dbo.NameStyle datatypedbo.NameStyleUser Defined Data Type 2
dbo.Phone datatypedbo.PhoneUser Defined Data Type 2
Procedure Source Code
CREATE PROCEDURE [dbo].[uspGetEmployeeManagers]
@EmployeeID [int]
AS

BEGIN
SET NOCOUNT ON;
WITH [EMP_cte]([EmployeeID], [ManagerID], [FirstName], [LastName], [Title], [RecursionLevel]) -- CTE name and columns
AS (
SELECT e.[EmployeeID], e.[ManagerID], c.[FirstName], c.[LastName], e.[Title], 0 -- Get the initial Employee
FROM [HumanResources].[Employee] e 
INNER JOIN [Person].[Contact] c 
ON e.[ContactID] = c.[ContactID]
WHERE e.[EmployeeID] = @EmployeeID
UNION ALL
SELECT e.[EmployeeID], e.[ManagerID], c.[FirstName], c.[LastName], e.[Title], [RecursionLevel] + 1 -- Join recursive member to anchor
FROM [HumanResources].[Employee] e 
INNER JOIN [EMP_cte]
ON e.[EmployeeID] = [EMP_cte].[ManagerID]
INNER JOIN [Person].[Contact] c 
ON e.[ContactID] = c.[ContactID]
)
SELECT [EMP_cte].[RecursionLevel], [EMP_cte].[EmployeeID], [EMP_cte].[FirstName], [EMP_cte].[LastName], 
[EMP_cte].[ManagerID], c.[FirstName] AS 'ManagerFirstName', c.[LastName] AS 'ManagerLastName'  -- Outer select from the CTE
FROM [EMP_cte] 
INNER JOIN [HumanResources].[Employee] e 
ON [EMP_cte].[ManagerID] = e.[EmployeeID]
INNER JOIN [Person].[Contact] c 
ON e.[ContactID] = c.[ContactID]
ORDER BY [RecursionLevel], [ManagerID], [EmployeeID]
OPTION (MAXRECURSION 25) 
END;
See Also

Related Objects

dbo Schema
AdventureWorks Database

 

 


© 2012 All Rights Reserved.

Send comments on this topic.