About This Blog

.net & SQL Samples, programming tips and tricks, performance tips, guidelines, and best practices

Tuesday, 27 March 2012

SQL Server # Storing Hierarchical Data – Parent Child n’th level # TSQL

Introduction

Today, I would like to explain one way in which we can store the HIERARCHICAL data in SQL tables. A general table structure which people come up to store this kind of data is -

1

Where, EmployeeID id the UniqueID alloted to every new employee record inserted into the table and ManagerID is the EmployeeID of the immediate manager of the employee. Keeping in mind that Manager is also an employee.

Problem Statement

This table structure very well serves the purpose as long as we have 1-Level hierarchy. However, if the hierarchy is of n'th level, the SELECT statement to fetch the records becomes more complex with this kind of table structure. Suppose, we want to fetch the complete TREE of a particular employee, i.e. list of all the employees who are directly or indirectly managed by a particular employee. How to do it……..?

Thanks to CTE’s for making the life a bit easier – as using them in a recursive manner, we can get the work done. Please follow this msdn link to see an implementation using recursive CTE.

Suggested Table Structure

2

Here, I have just included a new column [PATH]. It is of VARCHAR(MAX) type. I have taken it as VARCHAR(MAX) just to make sure the field is long enough to store the complete path. But one can assign appropriate size as per their system’s requirement.

The basic idea of the [path] column is to store the complete hierarchical path of any employee separated by a delimiter as under -

3

Calculating the new path is very simple. It’s just, {New Path} = {Parent Path} + {Self ID} + {Delimiter}

Now, suppose if I want to fetch all the employees who are directly or indirectly working under EmployeeID = 2, I can use the below tsql -

;WITH CTE AS (
SELECT 1 EmployeeID,NULL ManagerID, '\1\' [Path]
UNION ALL    
SELECT 2 EmployeeID,1 ManagerID, '\1\2\' [Path]
UNION ALL    
SELECT 3 EmployeeID,1 ManagerID, '\1\3\' [Path]
UNION ALL    
SELECT 4 EmployeeID,2 ManagerID, '\1\2\4\' [Path]
UNION ALL    
SELECT 5 EmployeeID,4 ManagerID, '\1\2\4\5\' [Path]
)
SELECT
  *
FROM
  CTE
WHERE
  [Path] LIKE '%\2\%'

We can use a simple logic to even find out the level of the Employee -


SELECT
  *,
  (LEN([Path]) - LEN(REPLACE([Path],'\',''))) - 2 [Level]
FROM
  CTE
WHERE
  [Path] LIKE '%\2\%'

4

2 is subtracted from the formula as the length of delimiter for Level-0 is 2.

Conclusion

Hope, this simple trick could save a lot of time for the ones who find themselves lost playing with the hierarchical data.

Monday, 12 March 2012

Last Execution Date Time of a Stored Procedure

On many forums I have found a very basic yet important query - “How can I know when was my Stored Procedure last executed?” And today through this blog I will try to answer this question.

Actually speaking, without explicit logging or tracing, it is not possible to get this information for each and every Stored Procedure of our Database. However, we can get this detail along with many other relevant information for the stored procedure having it’s execution plan currently cached on the server by using - sys.dm_exec_procedure_stats It’s a system dynamic view that returns aggregate performance statistics for cached stored procedures. Please note that this view has been introduced from SQL Server 2008.

The important thing to note is that this view returns one row for each cached stored procedure plan, and the lifetime of the row is as long as the stored procedure remains cached. When a stored procedure is removed from the cache, the corresponding row is eliminated from this view.

So, let’s see a way, using which at least we can find out the some important facts for the cached stored procedures -

USE DBName
GO
 
SELECT 
  O.name,
  PS.last_execution_time
FROM 
  sys.dm_exec_procedure_stats PS 
INNER JOIN sys.objects O 
  ON O.[object_id] = PS.[object_id] 

P.S. Please replace the DBName with the actual name of the Database.


The above script will return the name of all the cached stored procedure of the current database with their last execution time.


For more details on this dynamics view, please refer - sys.dm_exec_procedure_stats (Transact-SQL)