INF: How to Profile Transact-SQL Code in Stored Procedures and TriggersID: Q172117
|
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:
This article defines some common methods to profile Transact-SQL code in
SQL Server, if the following assumptions are true:
Q111405 : INF: SQL Server and Windows NT Thread Scheduling
Q165951 : INF: Result Processing for SQL Server
DECLARE @x datetime
SELECT @x = GetDate()
SELECT * FROM authors
SELECT DateDiff(millisecond, @x, GetDate())
CREATE PROCEDURE timeme AS
SELECT * FROM pubs..authors
RETURN
GO
CREATE TABLE profile
(id int primary key,
trials int not null default 0,
trltime int not null default 0)
GO
/* 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
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
INSERT profile (id) VALUES (Object_ID('timeme'))
GO
EXEC timeme
GO
SELECT Object_Name(id), trltime / trials FROM profile
GO
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
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
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
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
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
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,
fill1 char(250) not null default '',
fill2 char(250) not null default '',
fill3 char(250) not null default '',
fill4 char(250) not null default '')
GO
CREATE PROCEDURE timeme AS
IF DB_Name() <> 'pubs'
RETURN
SELECT * FROM authors
RETURN
GO
The following is the stored procedure with profiling code also handling
the Return commands:
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
IF DB_Name() <> 'pubs'
--RETURN
GOTO ENDME
SELECT * FROM pubs..authors
ENDME:
IF @debug = 1
UPDATE profile SET trials = trials + 1, trltime = trltime +
DateDiff(MILLISECOND, @ttime, GetDate())
WHERE id = @@procid
RETURN
GO
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,
tmin int not null default 1000000, -- minimum trial time
tmax int not null default 0, -- maximum trial time
tmint int not null default 0, -- trial number of minimum trial
tmaxt int not null default 0, -- trial number of maximum trial
fill1 char(255) not null default '',
fill2 char(255) not null default '',
fill3 char(255) not null default '',
fill4 char(255) not null default '')
GO
The changes to the stored procedure are to get the minimum and maximum
trial times when checking if it should be profiled. Also, one of three
updates is run, based on if the current trial is the new minimum, new
maximum, or just another trial.
CREATE PROCEDURE timeme AS
DECLARE @debug int
DECLARE @min int
DECLARE @max int
SELECT @debug = enabled, @min = tmin, @max = tmax FROM profile WHERE
id = @@procid
IF @debug = 1
BEGIN
DECLARE @ttime datetime
DECLARE @itime int
SELECT @ttime = GetDate()
END
SELECT * FROM pubs..authors
IF @debug = 1
BEGIN
SELECT @itime = DateDiff(MILLISECOND, @ttime, GetDate())
SELECT @itime
IF @min > @itime
UPDATE profile SET trials = trials + 1, trltime = trltime +
@itime, tmin = @itime, tmint = trials
WHERE id = @@procid
ELSE
IF @max < @itime
UPDATE profile SET trials = trials + 1, trltime = trltime +
@itime, tmax = @itime, tmaxt = trials
WHERE id = @@procid
ELSE
UPDATE profile SET trials = trials + 1, trltime = trltime +
@itime WHERE id = @@procid
END
RETURN
GO
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,
t1 int not null default 0,
t1time int not null default 0,
t2 int not null default 0,
t2time int not null default 0,
fill1 char(255) not null default '',
fill2 char(255) not null default '',
fill3 char(255) not null default '',
fill4 char(255) not null default '')
GO
The following is a sample stored procedure to use as a basis for this
method:
CREATE PROCEDURE timeme AS
SELECT * FROM pubs..authors
SELECT * FROM pubs..titleauthor
SELECT * FROM pubs..titles
RETURN
GO
Assume that you want to know the total time for the procedure, the first
two queries, and only the first query. The following stored procedure is
modified to profile this information:
CREATE PROCEDURE timeme AS
DECLARE @debug int
SELECT @debug = enabled FROM profile WHERE id = @@procid
IF @debug = 1
BEGIN
DECLARE @ttime datetime
DECLARE @t1time datetime
DECLARE @t2time datetime
DECLARE @t1 int
DECLARE @t2 int
SELECT @ttime = GetDate()
END
IF @debug = 1
BEGIN
SELECT @t1time = GetDate()
SELECT @t2time = GetDate()
SELECT * FROM pubs..authors
SELECT @t1 = DateDiff(MILLISECOND, @t1time, GetDate())
END
SELECT * FROM pubs..titleauthor
IF @debug = 1
SELECT @t2 = DateDiff(MILLISECOND, @t2time, GetDate())
SELECT * FROM pubs..titles
IF @debug = 1
UPDATE profile SET trials = trials + 1, trltime = trltime +
DateDiff(MILLISECOND, @ttime, GetDate()), t1time = t1time + @t1,
t1 = t1 + 1, t2time = t2time + @t2, t2 = t2 + 1
WHERE id = @@procid
RETURN
GO
Note that this method can also profile performance of extended stored
procedure calls as well as remote stored procedure calls.
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