Key lock 的秘密
研究死锁,或者观察sp_lock,有时候最恼人的莫过于你看到下面研究成果的key lock,但是却不知道究竟是哪个page 哪个row被lock住了:
Exec sp_lock:
就说上面的key (9dd27be994c0) 吧,能不能知道这个key,究竟是对应于那个table,那个data page,甚至哪一行(row)呢?
可以的。且听我慢慢说来。
先说这一行:
52 20 978102525 2 KEY (9dd27be994c0) X GRANT
其中20就是dbid了,indid 2表示是nonclustered index,而978102525就是objectid了。这个比较好懂。你可以使用Select object_name(978102525)来得到表的名字:
而Key (9dd27be994c0)其实是键值的哈希(hash)值。Hash出来的值,你无法逆向得到它的键值。但是幸运的是,你可以使用微软的undocumented的宏, %%lockres%% ,来对表的所有键进行一次同样的hash运算,然后你就可以从hash的结果集里面找到你想要的键值啦。首先,需要知道index为2的是那个index:
select name,index_id,type_desc from sys.indexes where object_id=object_id('test')
name
index_id type_desc
--------------- ----------- ---------------------
cidx1 1 CLUSTERED
idx1 2 NONCLUSTERED
然后就可以使用 %%lockres%% 了:
SELECT %%lockres%% 'key', test.* FROM test with(index(idx1))
或者:
SELECT %%lockres%% 'key', test.* FROM test with(index=2)
结果如下:
你可以看到,对应sp_lock 的key的hash为9dd27be994c0的行,就是c1=2的那行。简单点你甚至可以使用下面 的语句直接得到某个key hash值的行:
SELECT %%lockres%% 'key', test.* FROM test with(index(idx1)) where %%lockres%% ='(9dd27be994c0)'
再进一步,能否得到该行对应的page和fileid呢?这个就需要使用另一个undocumented的宏 . %%physloc%% 了:
select %%physloc%%,test.* from test with(index(idx1))
上面的返回值是一个十六进制的值,表示page,file,和slot id。可以使用sys.fn_physlocformatter函数将它转换成一个可读的(file:page:slot)格式的值:
select %%physloc%%,sys.fn_physlocformatter(%%physloc%%) 'physical location',test.* from test with(index(idx1))
结果如下:
对应第二行数据的,就在37828这个page了。这个时候,你可以使用DBCC PAGE来打印出它的内容,探究slot为2 的那行:
dbcc traceon(3604)
dbcc page(20,1,37828,1)
结果:
PAGE: (1:37828)
BUFFER:
BUF @0x00000000803BB400
bpage = 0x000000002CAA6000
bhash = 0x0000000000000000
bpageno = (1:37828)
bdbid = 20
breferences = 0
bcputicks = 0
bsampleCount = 0
bUse1 = 42097 bstat = 0x10b
blog = 0x5ab21c9a
bnext = 0x0000000000000000
PAGE HEADER:
Page @0x000000002CAA6000
m_pageId = (1:37828)
m_headerVersion = 1
m_type = 2
m_typeFlagBits = 0x0 m_level = 0 m_flagBits = 0x0
m_objId (AllocUnitId.idObj) = 194
m_indexId (AllocUnitId.idInd) = 256
Metadata: AllocUnitId = 72057594050641920
Metadata: PartitionId = 72057594046251008 Metadata: IndexId = 2
Metadata: ObjectId = 978102525
m_prevPage = (0:0)
m_nextPage = (0:0)
pminlen = 5
m_slotCnt = 5
m_freeCnt = 7997
m_freeData = 217 m_reservedCnt = 0 m_lsn = (17704:185:18)
m_xactReserved = 0
m_xdesId = (0:20808688)
m_ghostRecCnt = 0
m_tornBits = -1577081955
DB Frag ID = 1
Allocation Status
GAM (1:2) = ALLOCATED
SGAM (1:3) = ALLOCATED
PFS (1:32352) = 0x60 MIXED_EXT ALLOCATED 0_PCT_FULL DIFF (1:6) = CHANGED
ML (1:7) = NOT MIN_LOGGED
DATA:
Slot 0, Offset 0x60, Length 16, DumpStyle BYTE
Record Type = INDEX_RECORD
Record Attributes = NULL_BITMAP
VARIABLE_COLUMNS
Record Size = 16
Memory Dump @0x000000005166A060
0000000000000000: 36010000
00030000 01001000 61626364
6...........abcd
Slot 1, Offset 0x70, Length 22, DumpStyle BYTE
Record Type = INDEX_RECORD
Record Attributes = NULL_BITMAP
VARIABLE_COLUMNS
Record Size = 22
Memory Dump @0x000000005166A070
0000000000000000: 36010000
00030000 02001200 16006162 63640100
6.............abcd..
0000000000000014: 0000
..
Slot 2, Offset 0xc9, Length 16, DumpStyle BYTE
Record Type = INDEX_RECORD Record Attributes = NULL_BITMAP VARIABLE_COLUMNS
Record Size = 16
Memory Dump @0x000000005166A0C9
0000000000000000: 36020000
00030000 01001000 31323334
6...........1234
Slot 3, Offset 0x96, Length 18, DumpStyle BYTE
Record Type = INDEX_RECORD
Record Attributes = NULL_BITMAP
VARIABLE_COLUMNS
Record Size = 18
Memory Dump @0x000000005166A096
0000000000000000: 36030000
00030000 01001200 65656566 6666
6...........eeefff
Slot 4, Offset 0xa8, Length 17, DumpStyle BYTE
Record Type = INDEX_RECORD
Record Attributes = NULL_BITMAP
VARIABLE_COLUMNS
Record Size = 17
Memory Dump @0x000000005166A0A8
0000000000000000: 36040000
00030000 01001100 38397070 70
6...........89ppp
OFFSET TABLE:
Row - Offset
4 (0x4) - 168 (0xa8)
3 (0x3) - 150 (0x96)
2 (0x2) - 201 (0xc9)
1 (0x1) - 112 (0x70)
0 (0x0) - 96 (0x60)
DBCC execution completed. If DBCC printed error messages, contact your system administrator.
注意,这个行就是index record,和indid=2完全吻合。