The following query demonstrates how to list the employees by management level. Level 0 represents employees with no managers. Level 1 represents employees who report directly to one of the level 0 managers, level 2 represents employees who report directly to a level 1 manager, and so on.
WITH RECURSIVE manager ( EmployeeID, ManagerID, GivenName, Surname, mgmt_level ) AS ( ( SELECT EmployeeID, ManagerID, -- initial subquery GivenName, Surname, 0 FROM Employees AS e WHERE ManagerID = EmployeeID ) UNION ALL ( SELECT e.EmployeeID, e.ManagerID, -- recursive subquery e.GivenName, e.Surname, m.mgmt_level + 1 FROM Employees AS e JOIN manager AS m ON e.ManagerID = m.EmployeeID AND e.ManagerID <> e.EmployeeID AND m.mgmt_level < 20 ) ) SELECT * FROM manager ORDER BY mgmt_level, Surname, GivenName; |
The condition within the recursive query that restricts the management level to less than 20 is an important precaution. It prevents infinite recursion in the event that the table data contains a cycle.
The max_recursive_iterations option is designed to catch runaway recursive queries. The default value of this option is 100. Recursive queries that exceed this number of levels of recursion end, but cause an error.
Although this option may seem to diminish the importance of a stop condition, this is not usually the case. The number of rows selected during each iteration may grow exponentially, seriously impacting database performance before the maximum is reached. Stop conditions within recursive queries provide a means of setting appropriate limits in each situation.
Send feedback about this page via email or DocCommentXchange | Copyright © 2008, iAnywhere Solutions, Inc. - SQL Anywhere 11.0.0 |