SQL Server Profiler – a tutorial


During all kinds of database interaction there are times when you want to see what is actually being sent to the database, the actual queries that are executed by the database engine. Some times you have 3rd party apps that do all kinds of different stuff under the hood, or maybe you have inherited a website from some developer that made a serious spaghetti of everything. The only way of knowing what is really going on in the database is to use SQL Server Profiler.

Now, although profiler is a simple yet *very* powerful tool, it does take some tweaking to make it work they way you want it to. It comes with some default templates but in my experience they are not nearly good enough to be useful in a working environment. There are a whole bunch of objects/events that can be monitored but what I’m gonna do is show you how to make a trace template that will provide the information you need most of the time.

Here is the order of things you need to do:

  1. First of all you need to open up Profiler. You can either find it in the Tools menu in SQL Server Management Studio, or you can find it on the Windows Start Menu under Microsoft SQL Server -> Performance Tools.
  2. When Profiler opens it will ask you to connect to the server you want to profile. Click “Cancel” in this window, no connection is needed to create a Profiler Template like we are doing now.
  3. You should now have a blank Profiler window and it’s time to create the new template. Go to File -> Templates and then click “New Template”
  4. The General window of the Template generator pops up and you need to fill out the selected server type for the template and a new template name. I usually go for “MyTemplate” (quite original right :) as the name  as I usually only have one custom template in there. You should also check “Base the new template on an existing one” and choose “TSQL_Duration” as your existing template. Finally check the last checkbox to make this the default template for new traces. Do NOT click Save!
  5. Now you need to click “Event Selection” which is the second tab in the open window and for people not familiar with Profiler this is where the tricky part starts. After all, how do you know which events you need to choose if you’ve never used it before??
  6. Since we chose to base the new template on an existing one (TSQL_duration), the events selection window will be preconfigured with some events. Be aware that the two events that are chosen will only take in to account those queries/procedures that have actually finished. Check the checkbox in the lower right part of the window that says “Show all columns”. A bunch of checkboxes will appear next to the two preconfigured events.
  7. Now you need to do the following:
    • Remove the checkbox for the column BinaryData for the event RPC:Completed.

    Then make sure that the following checkboxes are checked for BOTH events:

    • Duration (the number of milliseconds it took to run the query)
    • TextData (the actual sql query text/stored procedure call that is sent to the database, including parameters)
    • SPID (the system process ID of the current connection)
    • ApplicationName (the name of the application the query/procedure originates from, could sometimes be empty)
    • DatabaseName (the database name the query is sent to)
    • HostName (the server name of the server sending the query)
    • LoginName (the username of the authenticated user that opened the connection)
    • StartTime (the timestamp when the query was started)
  8. Ok, we’ve come a long way now! What we need to do now is to set some Column Filters so our traces wont be cluttered with mumbo-jumbo that is not relevant to what we are doing:
    • Uncheck the “Show all columns”
    • Click “Column Filters”
  9. Setting the correct Column Filters is essential to getting good trace output and if you don’t do it right your trace might get flooded a lot of stuff that will make it harder for you to find what you’re looking for. And the only column filter we will set for the *template* is a SPID filter of Greater than or equal to 50. All SPIDs that have a number less than 50 are reserved for internal processes and are usually not of any value to us. Also make sure that the “Exclude rows that do not contain values” is checked. Click OK to save your column filters. When at a later stage you are  using this template, it will be useful to add additional filters. Remember that this is only a template, so when your’e running a trace using this template you can change all the events and columns and filters to your liking. What I usually do though is to create filters on the TextData (the sql query/procedure that is being exeuted) or the DatabaseName. Filters are ususlly specified as LIKE with a value of i.e “%CREATE TABLE%” (without any quotation marks) or %MyDatabaseName% and always remember to check the “Exclude rows that do not contain values” when making filters.
  10. Now you need to click “Organize Columns”. And I have always found Profiler to be a little weird when it comes to this organizing, because Profiler actually sorts the output of the trace according to the order you specify here. This in itself might not be so weird but the fact that it is impossible to sort the output of a trace after it has started makes this step really important! And it took me quite a while to figure it out actually :) And to me at least it’s vital that the trace is always sorted by StartTime. If you sort by StartTime it has no real importance what the order of the other columns are so these can be put in whichever order you prefer. After your finished organizing your windows should look more or less like this. The important thing is that the StartTime is on top!
  11. Once you have done all this you are set to go, and all you need to do now is to click “Save”. Your template is done!
  12. To test the newly created template you need to start a new trace by going to File -> New Trace. You need to log on to the server you want to trace, and once you have done that the new trace window will open. If you set the template you just created to be the default template it will automatically be selected for you, if not you will have to select it manually in the “Use the template” dropdown.
  13. Click Run and all new trace events that satisfy your filters will now appear in the order of when they were started :) By selecting one or more lines (use the Ctrl-key to select several)  the actual t-sql that was sent to the database will be displayed in the details window. If you select several lines, they will be separated by the GO statement automatically. 

Happy Tracing!

Advertisements

Mirroring between two stand-alone servers using certificates


Mirroring is usually done between two servers inside the same network where both servers are a part of a domain and have a trusted authentication mechanism provided by Active Directory. But what if this is not the case? What if you have your mirroring partners in separate networks or in separate data centers even, where there is no trusted authentication possible?

There is still hope, and the solution is to use SQL Server certificates. Here are the scripts you need to set up mirroring between a PRINCIPAL and a MIRROR server using certificates.

PLEASE NOTE: you can not simply copy and paste these scripts in to SQL Server Management Studio, press F5 and expect everything to work. You need to run each individual statement by itself, and some times you will need to run scripts on the mirror before progressing on the principal (i.e you need to create and do a backup of the certificate on the mirror before importing it to the principal, obviously)

--> This is the setup of the PRINCIPAL (master) in a mirroring environment

USE master
GO

CREATE MASTER KEY ENCRYPTION BY PASSWORD = 'password';
GO

--> Create a name not using "master" or "principal", remember: the roles can 
--  switch but the certificates remain the same. 
CREATE CERTIFICATE SQLSrv1_mirroring_cert 
   WITH SUBJECT = 'SQLSrv1 certificate',
      START_DATE = '2009-01-01 00:00:00',
      EXPIRY_DATE = '2030-01-01 00:00:00'
GO

CREATE ENDPOINT Mirroring_Endpoint
   STATE = STARTED
   AS TCP (
      LISTENER_PORT = 7024, 
      LISTENER_IP = ALL
   ) 
   FOR DATABASE_MIRRORING ( 
      AUTHENTICATION = CERTIFICATE SQLSrv1_mirroring_cert, 
      ENCRYPTION = REQUIRED ALGORITHM AES, 
      ROLE = ALL
   )
GO

--> Backup certificate and transfer to SQLSrv2
BACKUP CERTIFICATE SQLSrv1_mirroring_cert TO FILE = 'C:\SQLSrv1_mirroring_cert.cer';
GO

--> Create a login for the other server process
CREATE LOGIN SQLSrv2_mirroring_login WITH PASSWORD = 'password';
GO

--> Create a user for the new login 
CREATE USER SQLSrv2_mirroring_user FOR LOGIN SQLSrv2_mirroring_login;
GO

--> Associate the certificate with the user.
CREATE CERTIFICATE SQLSrv2_cert
   AUTHORIZATION SQLSrv2_mirroring_user
   FROM FILE = 'C:\SQLSrv2_mirroring_cert.cer'
GO

--> Grant the user access to the endpoint 
GRANT CONNECT ON ENDPOINT::Mirroring_Endpoint TO [SQLSrv2_mirroring_login]
GO

--> Create a FULL BACKUP of each database to be mirrored
BACKUP DATABASE mojo TO DISK = 'D:\SQLbackup\mojo_20090211.bak'

--> Restore these databases to the MIRROR using NORECOVERY

--> Set up partnering between the mirror and the principal (use a fully qualified name or an IP address)

--> Set up partnering between the principal and the mirror (use a fully qualified name or an IP address)
ALTER DATABASE mojo SET PARTNER ='tcp://sqlsrv2:7024'
GO
--> This is the setup of the MIRROR (slave) in a mirroring environment

USE master
GO

--> Make sure a master key is set 
CREATE MASTER KEY ENCRYPTION BY PASSWORD = 'password';
GO

--> 
CREATE CERTIFICATE SQLSrv2_mirroring_cert 
   WITH SUBJECT = 'SQLSrv2 certificate',
      START_DATE = '2009-01-01 00:00:00',
      EXPIRY_DATE = '2030-01-01 00:00:00'
GO

CREATE ENDPOINT Mirroring_Endpoint
   STATE = STARTED
   AS TCP (
      LISTENER_PORT = 7024, 
      LISTENER_IP = ALL
   ) 
   FOR DATABASE_MIRRORING ( 
      AUTHENTICATION = CERTIFICATE SQLSrv2_mirroring_cert, 
      ENCRYPTION = REQUIRED ALGORITHM AES, 
      ROLE = ALL
   )
GO

--> Backup certificate and transfer to SQLSrv1
BACKUP CERTIFICATE SQLSrv2_mirroring_cert TO FILE = 'C:\SQLSrv2_mirroring_cert.cer';
GO

--> Create a login for the other server process
CREATE LOGIN SQLSrv1_mirroring_login WITH PASSWORD = 'password'
GO

--> Create a user for the new login 
CREATE USER SQLSrv1_mirroring_user FOR LOGIN SQLSrv1_mirroring_login;
GO

--> Associate the certificate with the user.
CREATE CERTIFICATE SQLSrv1_mirroring_cert
   AUTHORIZATION SQLSrv1_mirroring_user
   FROM FILE = 'C:\SQLSrv1_mirroring_cert.cer'
GO

--> Grant the user access to the endpoint 
GRANT CONNECT ON ENDPOINT::Mirroring_Endpoint TO [SQLSrv1_mirroring_login]
GO

--> Copy a backup of the database(s) to be mirrored

--> Restore them using NORECOVERY
RESTORE DATABASE mojo
   FROM DISK='d:\SQLBackups\mojo_20090211.bak'
   WITH NORECOVERY
GO

--> Set up partnering between the mirror and the principal (use a fully qualified name or an IP address)
ALTER DATABASE mojo SET PARTNER ='tcp://sqlsrv1:7024'
GO

SQL Server Reporting Services performance monitoring


I’ve been doing a little bit of SSRS performance tuning lately and it has been somewhat of a challenge since I’m not all too familiar with Reporting Services. I was however thrilled when I found out about the ExecutionLog2-view in the ReportServer database and the fact that it has timings for the various parts of rendering each and every report that is run. The format of the view is somewhat self-explanatory but there is an xml column with some extra info that needs to be panned out as well, so I created this simple query to get it all out in a nice tabular format. (Detailed descriptions of the columns can be found on Robert Bruckners blog: http://blogs.msdn.com/b/robertbruckner/archive/2009/01/05/executionlog2-view.aspx)

USE ReportServer
GO
SELECT TOP 100
  Report = REVERSE(LEFT(REVERSE(ReportPath),CHARINDEX('/', REVERSE(ReportPath),1)-1)),
  Username,
  Parameters,
  TimeStart,
  TotalDurationMS = DATEDIFF(ms, TimeStart, TimeEnd),
  DurationDataRetrievalMS = TimedataRetrieval,
  DurationProcessingMS = TimeProcessing,
  DurationRendering = TimeRendering,
  [RowCount],
  ReportSizeKB = CAST(ByteCount/1024.0 AS decimal(18, 2)),
  ProcessingEngine = CAST(AdditionalInfo.query('data(/AdditionalInfo/ProcessingEngine)') AS varchar(200)),
  ScalabilityPagination = CAST(AdditionalInfo.query('data(/AdditionalInfo/ScalabilityTime/Pagination)') AS varchar(200)),
  ScalabilityProcessing = CAST(AdditionalInfo.query('data(/AdditionalInfo/ScalabilityTime/Processing)') AS varchar(200)),
  EstMemPaginationKB = CAST(AdditionalInfo.query('data(/AdditionalInfo/EstimatedMemoryUsageKB/Pagination)') AS varchar(200)),
  EstMemProcessingKB = CAST(AdditionalInfo.query('data(/AdditionalInfo/EstimatedMemoryUsageKB/Processing)') AS varchar(200)),
  DBQueryTimes = CAST(AdditionalInfo.query('data(/AdditionalInfo/DataExtension/SQL)') AS varchar(200))  
FROM ExecutionLog2 WITH (NOLOCK)
WHERE ReportPath <> 'Unknown'
ORDER BY TimeStart DESC

How to monitor replication latency using code?


I while back I had the need for monitoring quite a few replicated databases, so I had to make a procedure to automate the monitoring process. This procedure will insert a tracer token for each publication and monitor how long it takes for the token to by committed at each subscriber.

CREATE PROCEDURE [dbo].[proc_replication_latency_monitor]
AS

-- Procedure created by Henning Frettem, www.thefirstsql.com

BEGIN

SET NOCOUNT ON

DECLARE 
  @PublishedDBName varchar(200),
  @SQL nvarchar(2000),
  @PublicationPK int, 
  @PublicationName varchar(200),
  @PublicationDatabase varchar(200),
  @TracerTokenID int,
  @Parmameters nvarchar(500)
  
DECLARE @Publications table (
  PublicationPK int IDENTITY(1, 1) PRIMARY KEY CLUSTERED,
  PublicationDatabase varchar(200),
  PublicationName varchar(200),
  TracerTokenID int,
  TracerTokenPostTime datetime
)

DECLARE @Latency table (
  PublicationPK int,
  DistributorLatency bigint,
  Subscriber sysname,
  SubscriberDB sysname,
  SubscriberLatency bigint,
  OverallLatency bigint
)

--> Cursor for fetching all publications in all databases
DECLARE curPublishedDatabases CURSOR LOCAL FAST_FORWARD FOR 
  SELECT [name] FROM sys.databases WHERE is_published > 0
  
OPEN curPublishedDatabases
FETCH curPublishedDatabases INTO @PublishedDBName
WHILE @@FETCH_STATUS = 0
  BEGIN 
    SET @SQL = N'SELECT ''' + @PublishedDBName + ''', [name] FROM ' + @PublishedDBName + '.dbo.syspublications'
    INSERT INTO @Publications (PublicationDatabase, PublicationName)
    EXEC sp_executesql @SQL
    
    FETCH NEXT FROM curPublishedDatabases INTO @PublishedDBName
  END

CLOSE curPublishedDatabases
DEALLOCATE curPublishedDatabases 

--> Cursor for posting tracer tokens
DECLARE curPublications CURSOR LOCAL FAST_FORWARD FOR 
  SELECT PublicationPK, PublicationDatabase, PublicationName FROM @Publications

OPEN curPublications
FETCH curPublications INTO @PublicationPK, @PublicationDatabase, @PublicationName
WHILE @@FETCH_STATUS = 0
  BEGIN 
    SET @Parmameters = N'@PublicationName varchar(200), @TracerTokenID_OUT int OUTPUT';
    SET @SQL = N'EXEC ' + @PublicationDatabase + '.sys.sp_posttracertoken @publication = @PublicationName, @tracer_token_id = @TracerTokenID_OUT OUTPUT'
    EXEC sp_executesql @SQL, @Parmameters, @PublicationName = @PublicationName, @TracerTokenID_OUT = @TracerTokenID OUTPUT
  
    UPDATE @Publications SET 
      TracerTokenID = @TracerTokenID,
      TracerTokenPostTime = GETDATE()
    WHERE PublicationPK = @PublicationPK

    FETCH NEXT FROM curPublications INTO @PublicationPK, @PublicationDatabase, @PublicationName
  END
CLOSE curPublications
DEALLOCATE curPublications

--> Wait two minutes for all tokens to be commited at all subscribers
WAITFOR DELAY '000:02:00.000'

--> Then check the results for each posted token 
DECLARE curTokens CURSOR LOCAL FAST_FORWARD FOR 
  SELECT PublicationPK, PublicationDatabase, PublicationName, TracerTokenID FROM @Publications

OPEN curTokens
FETCH curTokens INTO @PublicationPK, @PublicationDatabase, @PublicationName, @TracerTokenID
WHILE @@FETCH_STATUS = 0
  BEGIN 
    --> Insert token history for each token 
    SET @SQL = N'EXEC ' + @PublicationDatabase + '.dbo.sp_helptracertokenhistory @publication = ''' + @PublicationName + ''', @tracer_id = ' + CAST(@TracerTokenID AS VARCHAR(50)) + ''
    INSERT INTO @Latency
      (DistributorLatency, Subscriber, SubscriberDB, SubscriberLatency, OverallLatency)
    EXEC sp_executesql @SQL

    --> Make sure that the PublicationPK is added to the token history
    UPDATE @Latency SET PublicationPK = @PublicationPK WHERE PublicationPK IS NULL
  
    --> Clean up the tracer token
    SET @SQL = N'EXEC ' + @PublicationDatabase + '.sys.sp_deletetracertokenhistory @publication = ''' + @PublicationName + ''', @tracer_id = ' + CAST(@TracerTokenID AS VARCHAR(50)) + ''
    EXEC sp_executesql @SQL

    FETCH NEXT FROM curTokens INTO @PublicationPK, @PublicationDatabase, @PublicationName, @TracerTokenID
  END
CLOSE curTokens
DEALLOCATE curTokens

SELECT 
  b.PublicationDatabase,
  b.PublicationName,
  a.Subscriber,
  a.SubscriberDB,
  a.OverallLatency,
  b.TracerTokenPostTime 
FROM @Latency a
  INNER JOIN @Publications b
    ON a.PublicationPK = b.PublicationPK

END

Create a full Point-In-Time restore script automatically!


A new version has been created! Check it out here: Updated: create point-in-time restore script automatically

Ok, I was sort of bored today so I figured I’d do something I’ve been wanting to do for a long time now.

It’s not very often you need to do a point-in-time restore but when you do you’re quite often in a big hurry. So I created a nice little script that will generate the entire point-in-time restore code for you automatically by only providing the name of the database and the point in time. All the scripts are generated from data in the backup-tables in the MSDB but for the actual restore scripts to work you’ll of course need the backup files in the same location as they were when you ran the backup.

Please note that the script only works on SQL Server 2008 (because of the format of the header/fillist tables).
Create a point-in-time restore automatically – SQL 2005 version

/*
Generate Point-in-time restore script, given only DBName and Point-in-time timestamp
Works only on SQL2008 databases!!

Script for generating restore script for full backup originally created by Michael
Valentine Jones, SQLTeam.com

The rest is created by Henning Frettem, www.thefirstsql.com
*/
SET NOCOUNT ON
GO

DECLARE
  @DBName varchar(200) = 'MyDB',
  @PointInTime datetime = '2010-08-09 09:10:00',
  @Filename varchar(200),
  @tab varchar(1) = char(9),
  @cr varchar(2) = char(13)+char(10),
  @Full_BackupStartDate datetime,
  @Diff_BackupStartDate datetime,
  @Log_BackupStartDate datetime,
  @SQL nvarchar(max) = ''

BEGIN TRY
  --> Performing some checks
  IF NOT EXISTS (SELECT 1 FROM msdb.dbo.backupset WHERE database_name = @DBName AND type = 'D' AND backup_start_date  @PointInTime)
    RAISERROR(N'No backup of the log exist after the specified PointInTime', 16, 1)

  --> Getting the filename and the date of the last full backup prior to the PointInTime
  SELECT TOP 1
    @Filename = b.physical_device_name,
    @Full_BackupStartDate = backup_start_date
  FROM msdb.dbo.backupset a
    INNER JOIN msdb.dbo.backupmediafamily b
      ON a.media_set_id = b.media_set_id
  WHERE a.database_name = @DBName
    AND a.type = 'D'
    AND a.backup_start_date  Create temp-tables for file header information
  DECLARE @header table (
    BackupName nvarchar(128),
    BackupDescription nvarchar(255),
    BackupType smallint,
    ExpirationDate datetime,
    Compressed bit,
    Position smallint,
    DeviceType tinyint,
    UserName nvarchar(128),
    ServerName nvarchar(128),
    DatabaseName nvarchar(128),
    DatabaseVersion int,
    DatabaseCreationDate datetime,
    BackupSize numeric(20,0),
    FirstLSN numeric(25,0),
    LastLSN numeric(25,0),
    CheckpointLSN numeric(25,0),
    DatabaseBackupLSN numeric(25,0),
    BackupStartDate datetime,
    BackupFinishDate datetime,
    SortOrder smallint,
    CodePage smallint,
    UnicodeLocaleId int,
    UnicodeComparisonStyle int,
    CompatibilityLevel tinyint,
    SoftwareVendorId int,
    SoftwareVersionMajor int,
    SoftwareVersionMinor int,
    SoftwareVersionBuild int,
    MachineName nvarchar(128),
    Flags  int,
    BindingID uniqueidentifier,
    RecoveryForkID uniqueidentifier,
    Collation nvarchar(128),
    FamilyGUID uniqueidentifier,
    HasBulkLoggedData bit,
    IsSnapshot bit,
    IsReadOnly bit,
    IsSingleUser bit,
    HasBackupChecksums bit,
    IsDamaged bit,
    BeginsLogChain bit,
    HasIncompleteMetaData bit,
    IsForceOffline bit,
    IsCopyOnly bit,
    FirstRecoveryForkID uniqueidentifier,
    ForkPointLSN numeric(25,0) NULL,
    RecoveryModel nvarchar(60),
    DifferentialBaseLSN numeric(25,0) NULL,
    DifferentialBaseGUID uniqueidentifier,
    BackupTypeDescription nvarchar(60),
    BackupSetGUID uniqueidentifier NULL,
    CompressedBackupSize bigint,
    Seq int NOT NULL identity(1,1)
    )

  --> Create temp-table for db file information
  DECLARE @filelist TABLE  (
    LogicalName nvarchar(128),
    PhysicalName nvarchar(260),
    Type char(1),
    FileGroupName nvarchar(128),
    Size numeric(20,0),
    MaxSize numeric(20,0),
    FileID bigint,
    CreateLSN numeric(25,0),
    DropLSN numeric(25,0) NULL,
    UniqueID uniqueidentifier,
    ReadOnlyLSN numeric(25,0) NULL,
    ReadWriteLSN numeric(25,0) NULL,
    BackupSizeInBytes bigint,
    SourceBlockSize int,
    FileGroupID int,
    LogGroupGUID uniqueidentifier NULL,
    DifferentialBaseLSN numeric(25,0) NULL,
    DifferentialBaseGUID uniqueidentifier,
    IsReadOnly bit,
    IsPresent bit,
    TDEThumbprint varbinary(32),
    Seq int NOT NULL identity(1,1)
    )

  --> Get header and filelist information from the backup file
  INSERT INTO @header
  EXEC ('RESTORE HeaderOnly FROM DISK = ''' + @Filename + '''')

  INSERT INTO @filelist
  EXEC ('RESTORE FilelistOnly FROM DISK = ''' + @Filename + '''')

  --> Generate the full backup restore script
  SELECT
    @SQL = @SQL +
      CASE
        WHEN a.Seq = 1 THEN
          @cr + 'RESTORE DATABASE [' + c.DatabaseName + ']' +
          @cr + 'FROM DISK =' + @cr + @tab + '''' +
          @Filename + '''' + @cr + 'WITH'
        ELSE ''
      END
      + @cr + @tab + 'MOVE ''' + a.LogicalName + ''' TO ''' + a.PhysicalName + ''','
      +
      CASE
        WHEN a.Seq = b.Seq THEN
          @cr + @tab + 'REPLACE, STATS = 5, NORECOVERY'
        ELSE ''
      END
  FROM
    @filelist a
    CROSS JOIN
      (SELECT Seq = MAX(b1.Seq) FROM @filelist b1 ) b
    CROSS JOIN
      (SELECT DatabaseName = MAX(c1.DatabaseName) FROM @header c1) c
  ORDER BY
    a.Seq

  SELECT @SQL = @SQL + @cr + 'GO' + @cr + @cr

  --> Restore the last differential backup if it exists
  SELECT TOP 1
    @SQL = @SQL + 'RESTORE DATABASE [' + @DBName + '] FROM DISK = ''' + b.physical_device_name + ''' WITH NORECOVERY' + @cr + 'GO',
    @Diff_BackupStartDate = a.backup_start_date
  FROM msdb.dbo.backupset a
    INNER JOIN msdb.dbo.backupmediafamily b
      ON a.media_set_id = b.media_set_id
  WHERE a.database_name = @DBName
    AND a.type = 'I'
    AND a.backup_start_date > @Full_BackupStartDate
    AND a.backup_start_date < @PointInTime   ORDER BY a.backup_start_date DESC      IF @Diff_BackupStartDate IS NULL     SET @Diff_BackupStartDate = @Full_BackupStartDate        --> Generate all log restores except the last one
  SELECT
    @SQL = @SQL + 'RESTORE LOG [' + @DBName + '] FROM DISK = ''' + b.physical_device_name + ''' WITH NORECOVERY' + @cr + 'GO' + @cr,
    @Log_BackupStartDate = a.backup_start_date
  FROM msdb.dbo.backupset a
    INNER JOIN msdb.dbo.backupmediafamily b
      ON a.media_set_id = b.media_set_id
  WHERE a.database_name = @DBName
    AND a.type = 'L'
    AND a.backup_start_date > @Diff_BackupStartDate
    AND a.backup_start_date < @PointInTime   ORDER BY a.backup_start_date      --> Generate last log restore script with the stopat command and recovery
  SELECT TOP 1
    @SQL = @SQL + 'RESTORE LOG [' + @DBName + '] FROM DISK = ''' + b.physical_device_name + '''
      WITH RECOVERY, STOPAT = ''' + CONVERT(varchar(20), @PointInTime, 120) + '''' + @cr + 'GO' + @cr
  FROM msdb.dbo.backupset a
    INNER JOIN msdb.dbo.backupmediafamily b
      ON a.media_set_id = b.media_set_id
  WHERE a.database_name = @DBName
    AND a.type = 'L'
    AND a.backup_start_date > @PointInTime
  ORDER BY a.backup_start_date ASC

  PRINT @SQL

END TRY
BEGIN CATCH
  PRINT ERROR_MESSAGE()
END CATCH

Finding the most active 15 minute time period


A guy over at sqlteam.com wanted to find the most active 15-minute period for a series of different stores his company runs and I thought this would be a nice topic for a blog post. I modified the problem a little to fit a sample table I had lying around and the result wasn’t too hard to come by.

Basically I have a table with sample call records for a telephone company and I want to find the most active 15-minute period where the most calls are started. First we have to generate a table with some sample data:

create table calls (
	call_id int identity(1, 1) primary key clustered,
	a_number bigint,
	b_number bigint,
	start_time datetime,
	duration int)
 go

--> Function to generate random numbers, used to create sample data
create function randomnumber (@min bigint, @max bigint, @rand float)
returns bigint
as
begin
	return CAST(((@Max + 1) - @Min) * @Rand + @Min AS bigint)
end
go

--&gt; Generate 500  rows of sample data
declare 
	@end int = 500,
	@current int = 1
	
while (@current <= @end)
	begin
		insert into calls (a_number, b_number, start_time, duration)
		select 
			dbo.randomnumber (22000000, 22999999, RAND()),
			dbo.randomnumber (22000000, 22999999, RAND()),
			DATEADD(MINUTE, dbo.randomnumber (1, 300, RAND()),GETDATE()),
			dbo.randomnumber (3, 3600, RAND())
			
		select @current = @current + 1
	end
go

Now once the test table with sample data has been established, we can run the actual query:

DECLARE @dummydate datetime = '2010-06-23 00:00:00'

;WITH cte AS (
	SELECT 
		[Mod] = DATEDIFF(MILLISECOND, @dummydate, start_time) % (15 * 60 * 1000), --&gt; 15 mins to milliseconds
		*
	FROM calls
	)
SELECT TOP 10 
	Period = DATEADD(MILLISECOND, -[Mod], start_time), 
	CountOfTransID = COUNT(call_id)
FROM cte
GROUP BY DATEADD(MILLISECOND, -[Mod], start_time)
ORDER BY COUNT(call_id) DESC

Last backups in a glance


As most other DBA’s I’m lazy and I try to make things as easy as possible for myself without missing out on anything. And the most important task of my day is to check the latest backups on all servers and I don’t think it can be done any easier than this. Unfortunately I don’t have the luxury of having all my servers registered in Management Studio because of security regulations but if you do, running this as a multi-server query should make things *reeeally* easy for you:

--> Latest backups
USE master
GO

SET NOCOUNT ON
GO

SELECT
  database_name,
  backup_finish_date = CASE
    WHEN db_backup_finish_date &gt; log_backup_finish_date THEN db_backup_finish_date
    ELSE log_backup_finish_date
    END
FROM (
  SELECT
    database_name = a.[name],
    db_backup_finish_date = 
      COALESCE(MAX(db_backup.backup_finish_date), '1900-01-01 00:00:00'),
    log_backup_finish_date = 
      COALESCE(MAX(log_backup.backup_finish_date), '1900-01-01 00:00:00')
  FROM sys.databases a
    LEFT OUTER JOIN msdb..backupset AS db_backup
      ON a.[name] = db_backup.database_name
        AND db_backup.[Type] = 'D'
    LEFT OUTER JOIN msdb..backupset AS log_backup
      ON db_backup.database_name = log_backup.database_name
        AND log_backup.[Type] = 'L'
  GROUP BY a.[name]
  ) AS dt