INF: How to Profile Transact-SQL Code in Stored Procedures and Triggers

ID: Q172117


The information in this article applies to:


SUMMARY

Profiling is used to tune code to make it more efficient or faster. Profiling is done by timing and counting the number of times a piece of code is executed, and recording the results so that the slow parts of the code can be identified. Then the code can be rewritten to be faster and more efficient. Profiling Transact-SQL code in SQL Server is sometimes difficult. However, profiling can provide the following information, which is sometimes necessary:

To provide some profiling capabilities, SQL Server provides the SET STATISTICS TIME and SET STATISTICS IO commands, as well as the following columns in the system table: sysprocesses, cpu, physical_io and last_batch, However, using these options may require changes to applications to handle the new results. This article provides methods you can use so that the client applications do not need to change; the stored procedures and triggers that the application uses are changed instead.


MORE INFORMATION

This article defines some common methods to profile Transact-SQL code in SQL Server, if the following assumptions are true:

Before proceeding, please note that profiling or debugging code does affect the amount of time the code takes to run.

The rest of this article is split into the following sections to make it more understandable:
  1. Simple Transact-SQL Time Profiling


  2. Simple Table-Based Stored Procedure and Trigger Profiling


  3. Advanced Table-Based Stored Procedure and Trigger Profiling


  4. Sample Stored Procedure to Manage Advanced Table-Based Profiling


  5. Additional Profiling Considerations


PART 1: Simple Transact-SQL Time Profiling

To perform a basic time performance test of a query such as "SELECT * FROM authors", you can wrap it in the following code:

   DECLARE @x datetime
   SELECT @x = GetDate()
   SELECT * FROM authors
   SELECT DateDiff(millisecond, @x, GetDate()) 

This method is very useful, but it does have some limitations. This method:
To resolve these limitations, you can use a profile table to hold results so that the average run time, as well as the number of times it was run, can be computed. Part 2 discusses this method below.

PART 2: Simple Table-Based Stored Procedure and Trigger Profiling

The following is an example stored procedure that is used as a basis in both Parts 2 and 3 of this article to display these methods:

   CREATE PROCEDURE timeme AS
   SELECT * FROM pubs..authors
   RETURN
   GO 

To perform time performance tests of a stored procedure or trigger, a table with the following definition is required:

   CREATE TABLE profile
   (id int primary key,
      trials int not null default 0,
      trltime int not null default 0)
   GO 

The following code would be added to the stored procedure to record performance:

   /* Add this code at the beginning of the stored procedure. */ 
   DECLARE @x datetime
   SELECT @x = GetDate()

   /* Add this code at the end of the stored procedure. */ 
   UPDATE profile SET trials = trials + 1, trltime = trltime +
   DateDiff(MILLISECOND, @x, GetDate()) WHERE id = @@procid 

The following is the modified stored procedure with the performance code added:

   CREATE PROCEDURE timeme AS
   DECLARE @x datetime
   SELECT @x = GetDate()
   SELECT * FROM pubs..authors
   UPDATE profile SET trials = trials + 1, trltime = trltime +
   DateDiff(MILLISECOND, @x, GetDate()) WHERE id = @@procid
   RETURN
   GO 

Finally, the following is the execution of the stored procedure with the result of adding the stored procedure to the profile table as well as reporting the performance:

   INSERT profile (id) VALUES (Object_ID('timeme'))
   GO
   EXEC timeme
   GO
   SELECT Object_Name(id), trltime / trials FROM profile
   GO 

This method is very useful but still has the limitation that profiling is not easily enabled and disabled. To resolve this limitation, the profile table needs to hold an enabled status, and the procedure needs to check if it should be profiled. Part 3 discusses this method below.

PART 3: Advanced Table-Based Stored Procedure and Trigger Profiling

The following is the updated profile table script for dynamic profiling:

   CREATE TABLE profile
   (id int primary key,
      enabled int not null default 0,
      trials int not null default 0,
      trltime int not null default 0)
   GO 

The following is the updated stored procedure for dynamic profiling:

   CREATE PROCEDURE timeme AS
   DECLARE @debug int
   SELECT @debug = enabled FROM profile WHERE id = @@procid
   IF @debug = 1
   BEGIN
      DECLARE @ttime datetime
      SELECT @ttime = GetDate()
   END
   SELECT * FROM pubs..authors
   IF @debug = 1
      UPDATE profile SET trials = trials + 1, trltime = trltime +
      DateDiff(MILLISECOND, @ttime, GetDate())
      WHERE id = @@procid
   RETURN
   GO 

Finally, the following is the execution of the stored procedure with the result of adding the stored procedure to the profile table as well as reporting the performance:

   INSERT profile (id) VALUES (Object_ID('timeme'))
   GO
   /* This run is not profiled because enabled is 1. */ 
   EXEC timeme
   GO
   UPDATE profile SET enabled = 1 WHERE id = Object_ID('timeme')
   GO
   EXEC timeme
   GO
   SELECT Object_Name(id), trltime / trials FROM profile
   GO 

PART 4: Sample Stored Procedure to Manage Advanced Table-Based Profiling


   CREATE PROCEDURE resetprofile AS
   /* Disables and effectively resets profiling data for all objects. */ 
   DELETE profile
   RETURN
   GO
   CREATE PROCEDURE setupprofile @name char(30) = NULL AS
   /* Adds a stored procedure or trigger to profile table. */ 
   IF @name IS NULL
      PRINT 'usage: setupprofile <procedure or trigger name>'
   ELSE
      IF Object_ID(@name) IS NOT NULL
         INSERT profile(id) VALUES (Object_ID(@name))
      ELSE
         PRINT 'Invalid object name'
   RETURN
   GO
   CREATE PROCEDURE enableprofile @name char(30) = NULL as
   /* Enables one or more stored procedures or triggers in the profile
   table for profiling. */ 
   IF @name IS NULL
      UPDATE profile SET enabled = 1
   ELSE
      IF Object_ID(@name) IS NOT NULL
         UPDATE profile SET enabled = 1 WHERE id = Object_ID(@name)
      ELSE
         PRINT 'Invalid object name'
   RETURN
   GO
   CREATE PROCEDURE disableprofile @name char(30) = NULL AS
   /* Disables one or more stored procedures or triggers in the profile
   table for profiling. */ 
   IF @name IS NULL
      UPDATE profile SET enabled = 0
   ELSE
      IF Object_ID(@name) IS NOT NULL
         UPDATE profile SET enabled = 0 WHERE id = Object_ID(@name)
      ELSE
         PRINT 'Invalid object name'
   RETURN
   GO
   CREATE PROCEDURE reportprofile AS
   /* Reports performance of enabled stored procedures and triggers. */ 
   SELECT name = Object_Name(id),  'trial avg' = CASE WHEN trials <> 0 THEN
   trltime / trials ELSE 0 END, trials FROM profile WHERE enabled = 1
   RETURN
   GO 

So you can change the run code of Part 3 above to the following:

   EXEC setupprofile 'timeme'
   GO
   /* This run is not profiled because enabled is 0. */ 
   EXEC timeme
   GO
   EXEC enableprofile 'timeme'
   GO
   EXEC timeme
   GO
   EXEC reportprofile
   GO 

PART 5: Additional Profiling Considerations

When performing Transact-SQL profiling with a table for results as described above, consider the following:


Additional query words: tsql transql t-sql tran-sql rpc RPCs


Keywords          : kbcode kbprg kbusage SSrvProg SSrvStProc SSrvTran_SQL 
Version           : 6.5
Platform          : WINDOWS 
Issue type        : kbhowto kbinfo 

Last Reviewed: April 15, 1999