Stored Procedures [dbo].[uspGetEmployeeManagers]
Stored procedure using a recursive query to return the direct and indirect managers of the specified employee.
PropertyValue
ANSI Nulls OnTrue
Quoted Identifier OnTrue
NameData TypeMax Length (Bytes)Description
@BusinessEntityIDint4Input parameter for the stored procedure uspGetEmployeeManagers. Enter a valid BusinessEntityID from the HumanResources.Employee table.

CREATE PROCEDURE [dbo].[uspGetEmployeeManagers]
   @BusinessEntityID [int]
AS
BEGIN
   SET NOCOUNT ON;

   -- Use recursive query to list out all Employees required for a particular Manager
   WITH [EMP_cte]([BusinessEntityID], [OrganizationNode], [FirstName], [LastName], [JobTitle], [RecursionLevel]) -- CTE name and columns
   AS (
       SELECT e.[BusinessEntityID], e.[OrganizationNode], p.[FirstName], p.[LastName], e.[JobTitle], 0 -- Get the initial Employee
       FROM [HumanResources].[Employee] e
           INNER JOIN [Person].[Person] as p
           ON p.[BusinessEntityID] = e.[BusinessEntityID]
       WHERE e.[BusinessEntityID] = @BusinessEntityID
       UNION ALL
       SELECT e.[BusinessEntityID], e.[OrganizationNode], p.[FirstName], p.[LastName], e.[JobTitle], [RecursionLevel] + 1 -- Join recursive member to anchor
       FROM [HumanResources].[Employee] e
           INNER JOIN [EMP_cte]
           ON e.[OrganizationNode] = [EMP_cte].[OrganizationNode].GetAncestor(1)
           INNER JOIN [Person].[Person] p
           ON p.[BusinessEntityID] = e.[BusinessEntityID]
   )
   -- Join back to Employee to return the manager name
   SELECT [EMP_cte].[RecursionLevel], [EMP_cte].[BusinessEntityID], [EMP_cte].[FirstName], [EMP_cte].[LastName],
       [EMP_cte].[OrganizationNode].ToString() AS [OrganizationNode], p.[FirstName] AS 'ManagerFirstName', p.[LastName] AS 'ManagerLastName'  -- Outer select from the CTE
   FROM [EMP_cte]
       INNER JOIN [HumanResources].[Employee] e
       ON [EMP_cte].[OrganizationNode].GetAncestor(1) = e.[OrganizationNode]
       INNER JOIN [Person].[Person] p
       ON p.[BusinessEntityID] = e.[BusinessEntityID]
   ORDER BY [RecursionLevel], [EMP_cte].[OrganizationNode].ToString()
   OPTION (MAXRECURSION 25)
END;
GO
EXEC sp_addextendedproperty N'MS_Description', N'Stored procedure using a recursive query to return the direct and indirect managers of the specified employee.', 'SCHEMA', N'dbo', 'PROCEDURE', N'uspGetEmployeeManagers', NULL, NULL
GO
EXEC sp_addextendedproperty N'MS_Description', N'Input parameter for the stored procedure uspGetEmployeeManagers. Enter a valid BusinessEntityID from the HumanResources.Employee table.', 'SCHEMA', N'dbo', 'PROCEDURE', N'uspGetEmployeeManagers', 'PARAMETER', N'@BusinessEntityID'
GO