High precision time measuring in SQL Server 2005 with the help from CLR and unsafe code
Update: I've created a muliti connection version which can be found here.
Usually time measuring in sql server is done in 2 ways: with the help of GetDate() function or with SET STATISTICS TIME ON.
For doing hardcore performance analysis where any time reduction counts you need more precise measuring capabilities and the two mentioned are only accurate to a milisecond order.
In SQL Server 2000 there was no practical way to change this.
SQL server 2005 to the rescue. It has DMV's which hold time in microseconds which is better. but they can't be always used to measure the duration of the statement. You could use profiler... but for the sake of the argument lets say we don't want to :)
With the use of CLR integration we can import the .Net features like System.Diagnostics.StopWatch. You can see how in this post which acctually prompted the stuff you're reading.
I found this post on using High-Performance time in C# which uses two Win32 functions called QueryPerformanceCounter() and QueryPerformanceFrequency().
Timer frequencies on my computer:
System.Diagnostics.StopWatch = 3579545 QueryPerformanceFrequency = 3200150000
Physics 101: Higher frequency = better precision.
Some problems with QueryPerformanceCounter can be found here. So like everything else some testing is advisable.
So lets see some code.
The C# project is also called SqlHiPerfTimer.
SqlHiPerfTimer.cs:
using Win32Timer;public partial class SqlHiPerfTimer {
private static readonly HiPerfTimer hiPerf = new HiPerfTimer();[Microsoft.SqlServer.Server.SqlFunction] <span class="kwrd">public</span> <span class="kwrd">static</span> <span class="kwrd">int</span> TimerStart() { hiPerf.Start(); <span class="kwrd">return</span> 0; } [Microsoft.SqlServer.Server.SqlFunction] <span class="kwrd">public</span> <span class="kwrd">static</span> <span class="kwrd">int</span> TimerStop() { hiPerf.Stop(); <span class="kwrd">return</span> 0; } [Microsoft.SqlServer.Server.SqlFunction] <span class="kwrd">public</span> <span class="kwrd">static</span> System.Data.SqlTypes.SqlDecimal TimerElapsedSeconds() { <span class="kwrd">return</span> (System.Data.SqlTypes.SqlDecimal)hiPerf.ElapsedSeconds; } [Microsoft.SqlServer.Server.SqlFunction] <span class="kwrd">public</span> <span class="kwrd">static</span> System.Data.SqlTypes.SqlDecimal TimerElapsedMilliseconds() { <span class="kwrd">return</span> (System.Data.SqlTypes.SqlDecimal)hiPerf.ElapsedMilliSeconds; } [Microsoft.SqlServer.Server.SqlFunction] <span class="kwrd">public</span> <span class="kwrd">static</span> <span class="kwrd">long</span> TimerFrequency() { <span class="kwrd">return</span> hiPerf.TimerFrequency; }
}
HiPerfTimer.cs:
using System.Runtime.InteropServices; using System.ComponentModel; using System.Threading;namespace Win32Timer { internal class HiPerfTimer { [DllImport("Kernel32.dll")] private static extern bool QueryPerformanceCounter(out long lpPerformanceCount);
[DllImport(<span class="str">"Kernel32.dll"</span>)] <span class="kwrd">private</span> <span class="kwrd">static</span> <span class="kwrd">extern</span> <span class="kwrd">bool</span> QueryPerformanceFrequency(<span class="kwrd">out</span> <span class="kwrd">long</span> lpFrequency); <span class="kwrd">private</span> <span class="kwrd">long</span> startTime, stopTime; <span class="kwrd">private</span> <span class="kwrd">long</span> freq; <span class="rem">// Constructor</span> <span class="kwrd">public</span> HiPerfTimer() { startTime = 0; stopTime = 0; <span class="kwrd">if</span> (QueryPerformanceFrequency(<span class="kwrd">out</span> freq) == <span class="kwrd">false</span>) { <span class="rem">// high-performance counter not supported </span> <span class="kwrd">throw</span> <span class="kwrd">new</span> Win32Exception(); } } <span class="rem">// Start the timer</span> <span class="kwrd">public</span> <span class="kwrd">void</span> Start() { startTime = 0; stopTime = 0; Thread.Sleep(0); QueryPerformanceCounter(<span class="kwrd">out</span> startTime); } <span class="rem">// Stop the timer</span> <span class="kwrd">public</span> <span class="kwrd">void</span> Stop() { QueryPerformanceCounter(<span class="kwrd">out</span> stopTime); } <span class="rem">// Returns the duration of the timer (in seconds)</span> <span class="kwrd">public</span> <span class="kwrd">double</span> ElapsedSeconds { get { <span class="kwrd">return</span> (<span class="kwrd">double</span>)(stopTime - startTime) / (<span class="kwrd">double</span>)freq; } } <span class="kwrd">public</span> <span class="kwrd">double</span> ElapsedMilliSeconds { get { <span class="kwrd">return</span> (<span class="kwrd">double</span>)(stopTime - startTime) / (<span class="kwrd">double</span>)freq / (<span class="kwrd">double</span>)1000; } } <span class="kwrd">public</span> <span class="kwrd">long</span> TimerFrequency { get { <span class="kwrd">return</span> freq; } } }
}
SQL Server 2005:
exec sp_configure 'clr enabled', 1 RECONFIGURE go create database testCLR go ALTER DATABASE testCLR SET TRUSTWORTHY ON go use testCLR go CREATE ASSEMBLY SqlHiPerfTimer FROM 'D:\Test\SqlHiPerfTimer.dll' WITH PERMISSION_SET = UNSAFE GO CREATE FUNCTION dbo.TimerStart() RETURNS int AS EXTERNAL NAME SqlHiPerfTimer.SqlHiPerfTimer.TimerStart GO CREATE FUNCTION dbo.TimerStop() RETURNS int AS EXTERNAL NAME SqlHiPerfTimer.SqlHiPerfTimer.TimerStop GO CREATE FUNCTION dbo.TimerElapsedSeconds() RETURNS decimal(38, 20) AS EXTERNAL NAME SqlHiPerfTimer.SqlHiPerfTimer.TimerElapsedSeconds GO CREATE FUNCTION dbo.TimerElapsedMilliSeconds() RETURNS decimal(38, 20) AS EXTERNAL NAME SqlHiPerfTimer.SqlHiPerfTimer.TimerElapsedMilliseconds GO CREATE FUNCTION dbo.TimerFrequency() RETURNS bigint AS EXTERNAL NAME SqlHiPerfTimer.SqlHiPerfTimer.TimerFrequency go declare @i int select @i=0; select dbo.TimerStart() as TimerStart while @i < 1000 begin select @i = @i + 1 end select @i select dbo.TimerStop() as TimerStop select dbo.TimerElapsedSeconds() as TimerElapsedSeconds select dbo.TimerElapsedMilliSeconds() as TimerElapsedMilliSeconds select dbo.TimerFrequency() as TimerFrequency go DROP FUNCTION dbo.TimerStart DROP FUNCTION dbo.TimerStop DROP FUNCTION dbo.TimerElapsedSeconds DROP FUNCTION dbo.TimerElapsedMilliSeconds DROP FUNCTION dbo.TimerFrequency go DROP ASSEMBLY SqlHiPerfTimer go use master drop database testCLR
Here i've used Unsafe code with P/Invoke so i had to use
ALTER DATABASE testCLR SET TRUSTWORTHY ON
You could use PERMISSION_SET = SAFE assembly code with signing the DLL and creating the asymetric key from it in SQL Server
if you don't want to do SET TRUSTWORTHY ON for a databse.
How to do that is well described in this post by Kent Tegels which is in my opinion a must read.
|