How do I get a blocked index name for a deadlock?

Monitor, diagnose and receive alerts to problems across your SQL Servers.

How do I get a blocked index name for a deadlock?

Postby Keith_Walton » Tue May 10, 2011 4:26 pm

Example:

Object blocked: Index/(Key) 72057618332712960

Process detail:
dbid: 8, object id: 72057618332712960, index id: (010086470766)


Both of these numbers are too long to be the object_id (INT) in sys.all_objects
Keith Walton
Chief Software Architect
NHXS
Keith_Walton
 
Posts: 17
Joined: Mon Jun 12, 2006 2:35 pm
Location: Sacramento CA

Postby Chris Spencer » Wed May 11, 2011 1:40 pm

Hi Keith

We get this value directly from the SQL Server error log. I've investigated why the value is so long and the best explanation I've come up with so far is here:

http://stackoverflow.com/questions/3540 ... -too-large

This seems to suggest that the values are hobt rather than object ids.

It might be worth doing as that page suggests and run the following inside the relevant database (id = 8 )

Code: Select all
SELECT hobt_id, object_name(p.[object_id]), index_id
FROM sys.partitions p
WHERE hobt_id = 72057618332712960


This isn't working for me at the moment, but it'd be interesting to see if it works for you.

Regards
Chris
Chris Spencer
Test Engineer
Red Gate
Chris Spencer
 
Posts: 301
Joined: Tue Aug 29, 2006 9:09 am
Location: Red Gate - Cambridge

Postby Keith_Walton » Wed May 11, 2011 6:54 pm

I got it to work. I had to join in sys.indexes to get index name:

Code: Select all
SELECT name FROM master..sysdatabases WHERE dbid = 8

USE support
GO


SELECT
   object_name(partitions.object_id)   AS [Table],
   indexes.name            AS [Index]

FROM
   sys.partitions            AS partitions

   INNER JOIN
   sys.indexes            AS indexes
   ON partitions.object_id         = indexes.object_id

WHERE
   hobt_id               = 72057618332712960



It would be cool if SQL Monitor would do this automatically.

Thanks
Keith Walton
Chief Software Architect
NHXS
Keith_Walton
 
Posts: 17
Joined: Mon Jun 12, 2006 2:35 pm
Location: Sacramento CA

Postby Chris Spencer » Thu May 12, 2011 11:25 am

Hi Keith

Yes that seems to do the trick!!

As deadlock alerting is a very important part of SQL Monitor, I've raised a few enhancements requests and bug reports.

SRP-4174 : Enhancement that you have requested here to get the values auto-decoded into something more meaningful.

SRP-4175 : Bug report as we are misleading users by suggesting that some value is an object id when it is in fact a hobt id.

SRP-4176 : A more comprehensive enhancement request suggesting that we move to using trace flag 1222 rather than 1204. (1204 is required for SQL Server 2000 support but I can imagine it's possible to use one or the other when appropriate). 1222 gives far better information.

Regards
Chris
Chris Spencer
Test Engineer
Red Gate
Chris Spencer
 
Posts: 301
Joined: Tue Aug 29, 2006 9:09 am
Location: Red Gate - Cambridge


Return to SQL Monitor Previous Versions

Who is online

Users browsing this forum: No registered users and 0 guests