SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Mysterious deadlocks on a heap table


Mysterious deadlocks on a heap table

Author
Message
merdikler
merdikler
Forum Newbie
Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)

Group: General Forum Members
Points: 3 Visits: 189
Hi all,

We have a highly transactional database. It was owned by a third party before but now both the database and the application is on our site and we are trying to improve this project. So, we have a big (902919 rows), heap table, which is getting bigger and bigger everyday and sometimes deadlocks occur. The table has only 4 columns, "token", "type", "value" and "cacheTime", unique index cannot be created. It has one index on "token"(char(36)) and "type"(varchar(50)) ("value" should also be included but it is nvarchar(max)).

We are trying to understand the causes of these deadlocks and how to solve them, so I decided to post here. I'd really appreciate it if you can help me.



<deadlock-list>
<deadlock victim="process670ba10c8">
<process-list>
<process id="process670ba10c8" taskpriority="0" logused="0" waitresource="RID: 6:1:14949918:1" waittime="417" ownerId="347523711" transactionname="SELECT" lasttranstarted="2014-07-01T17:43:35.233" XDES="0x117cf7da40" lockMode="S" schedulerid="62" kpid="10832" status="suspended" spid="105" sbid="0" ecid="0" priority="0" trancount="0" lastbatchstarted="2014-07-01T17:43:35.233" lastbatchcompleted="2014-07-01T17:43:35.230" lastattention="1900-01-01T00:00:00.230" clientapp="Microsoft SQL Server JDBC Driver" hostname="EXPWEB1" hostpid="0" loginname="expuser" isolationlevel="read committed (2)" xactid="347523711" currentdb="6" lockTimeout="4294967295" clientoption1="671088672" clientoption2="128056">
<executionStack>
<frame procname="adhoc" line="1" stmtstart="74" sqlhandle="0x02000000e0a92205aebcb9dd3f38539312f56b0c41af55990000000000000000000000000000000000000000">
select token, type, value from cache where token=@P0 and type=@P1 </frame>
<frame procname="unknown" line="1" sqlhandle="0x0000000000000000000000000000000000000000000000000000000000000000000000000000000000000000">
unknown </frame>
</executionStack>
<inputbuf>
(@P0 varchar(8000),@P1 varchar(8000))select token, type, value from cache where token=@P0 and type=@P1 </inputbuf>
</process>
<process id="processd4e8f2188" taskpriority="0" logused="140" waitresource="KEY: 6:72057594116440064 (0833cce7ed16)" waittime="417" ownerId="347523709" transactionname="implicit_transaction" lasttranstarted="2014-07-01T17:43:35.230" XDES="0xccc9c3348" lockMode="X" schedulerid="64" kpid="20536" status="suspended" spid="103" sbid="0" ecid="0" priority="0" trancount="2" lastbatchstarted="2014-07-01T17:43:35.230" lastbatchcompleted="2014-07-01T17:43:35.230" lastattention="1900-01-01T00:00:00.230" clientapp="Microsoft SQL Server JDBC Driver" hostname="EXPWEB1" hostpid="0" loginname="expuser" isolationlevel="read committed (2)" xactid="347523709" currentdb="6" lockTimeout="4294967295" clientoption1="671088672" clientoption2="128058">
<executionStack>
<frame procname="adhoc" line="1" stmtstart="74" sqlhandle="0x0200000023b477359eec278e4060e11f3a1c194cbed41cc10000000000000000000000000000000000000000">
delete cache where token=@P0 and type=@P1 </frame>
<frame procname="unknown" line="1" sqlhandle="0x0000000000000000000000000000000000000000000000000000000000000000000000000000000000000000">
unknown </frame>
</executionStack>
<inputbuf>
(@P0 varchar(8000),@P1 varchar(8000))delete cache where token=@P0 and type=@P1 </inputbuf>
</process>
</process-list>
<resource-list>
<ridlock fileid="1" pageid="14949918" dbid="6" objectname="Exp.dbo.cache" id="lockc2e4e1500" mode="X" associatedObjectId="72057594046644224">
<owner-list>
<owner id="processd4e8f2188" mode="X"/>
</owner-list>
<waiter-list>
<waiter id="process670ba10c8" mode="S" requestType="wait"/>
</waiter-list>
</ridlock>
<keylock hobtid="72057594116440064" dbid="6" objectname="Exp.dbo.cache" indexname="ix_token_type" id="lock953b02280" mode="U" associatedObjectId="72057594116440064">
<owner-list>
<owner id="process670ba10c8" mode="S"/>
</owner-list>
<waiter-list>
<waiter id="processd4e8f2188" mode="X" requestType="convert"/>
</waiter-list>
</keylock>
</resource-list>
</deadlock>
</deadlock-list>
GilaMonster
GilaMonster
SSC Guru
SSC Guru (87K reputation)SSC Guru (87K reputation)SSC Guru (87K reputation)SSC Guru (87K reputation)SSC Guru (87K reputation)SSC Guru (87K reputation)SSC Guru (87K reputation)SSC Guru (87K reputation)

Group: General Forum Members
Points: 87005 Visits: 45267
Please post the table definition and all indexes on it.

Gail Shaw
Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

We walk in the dark places no others will enter
We stand on the bridge and no one may pass


merdikler
merdikler
Forum Newbie
Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)

Group: General Forum Members
Points: 3 Visits: 189
CREATE TABLE [dbo].[cache](
[token] [char](36) NULL,
[type] [varchar](50) NOT NULL,
[value] [nvarchar](max) NOT NULL,
[cacheTime] [datetime] NULL
) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]

CREATE NONCLUSTERED INDEX [IND_cache_token_type] ON [dbo].[cache]
(
[token] ASC,
[type] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
GO
GilaMonster
GilaMonster
SSC Guru
SSC Guru (87K reputation)SSC Guru (87K reputation)SSC Guru (87K reputation)SSC Guru (87K reputation)SSC Guru (87K reputation)SSC Guru (87K reputation)SSC Guru (87K reputation)SSC Guru (87K reputation)

Group: General Forum Members
Points: 87005 Visits: 45267
I think you have a key lookup deadlock here (ref https://www.simple-talk.com/sql/performance/sql-server-deadlocks-by-example/)

Can you make that existing index clustered?

Gail Shaw
Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

We walk in the dark places no others will enter
We stand on the bridge and no one may pass


ALZDBA
ALZDBA
SSChampion
SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)

Group: General Forum Members
Points: 12093 Visits: 8924
If you make that existing index the clustering index, make sure to set a suitable fill factor to avoid the need for page splits ( and the according waits / risk for deadlocks )
Investigate the behavior of the index key columns should help out.

Johan


Dont drive faster than your guardian angel can fly ...
but keeping both feet on the ground wont get you anywhere w00t

- How to post Performance Problems
- How to post data/code to get the best help


- How to prevent a sore throat after hours of presenting ppt ?


press F1 for solution, press shift+F1 for urgent solution :-D


Need a bit of Powershell? How about this

Who am I ? Sometimes this is me Alien but most of the time this is me Hehe
TheSQLGuru
TheSQLGuru
SSChampion
SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)

Group: General Forum Members
Points: 12355 Visits: 8548
Mark down my vote for a clustered index too - with appropriate fill factor as mentioned. Token is looking VERY much like something that will have values spread throughout the range of characters almost certainly a GUID given the size. If it is, I would start with something like 70% fill factor and run regular maintenance. The problem with HEAP and is you leave pages around that are emptied out to some degree and that space never gets unlinked from the table. The key lookups also cause 2 sets of locks which are likely the primary reason for the deadlocks.

Best,
Kevin G. Boles
SQL Server Consultant
SQL MVP 2007-2012
TheSQLGuru on googles mail service
merdikler
merdikler
Forum Newbie
Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)

Group: General Forum Members
Points: 3 Visits: 189
I dropped the existing index and made it clustered with 70% fill factor. We are monitoring the database and I hope we'll see no more deadlocks, I'll post again if this won't help.

Thank you all.
Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)

Group: General Forum Members
Points: 85639 Visits: 41082
{EDIT} Please ignore the following. I can't find the article where I saw this and I haven't been able to reproduce it in code. I have to retract this assertion.

I'll also add that some of the ad-hoc code that appears in the deadlock graph would concern me. Consider the following lines from the deadlock graph....

<inputbuf>
(@P0 varchar(8000),@P1 varchar(8000))select token, type, value from cache where token=@P0 and type=@P1 </inputbuf>

<inputbuf>
(@P0 varchar(8000),@P1 varchar(8000))delete cache where token=@P0 and type=@P1
</inputbuf>



Now, let's look at the definition of the table...

CREATE TABLE [dbo].[cache](
[token] [char](36) NULL,
[type] [varchar](50) NOT NULL,
[value] [nvarchar](max) NOT NULL,
[cacheTime] [datetime] NULL
) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]

CREATE NONCLUSTERED INDEX [IND_cache_token_type] ON [dbo].[cache]
(
[token] ASC,
[type] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
GO




Do you see any disparity between the ad-hoc code data-types and the table data-types that just might cause some unnecessary implicit conversions?


--Jeff Moden

RBAR is pronounced ree-bar and is a Modenism for Row-By-Agonizing-Row.
First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column.
If you think its expensive to hire a professional to do the job, wait until you hire an amateur. -- Red Adair

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
GilaMonster
GilaMonster
SSC Guru
SSC Guru (87K reputation)SSC Guru (87K reputation)SSC Guru (87K reputation)SSC Guru (87K reputation)SSC Guru (87K reputation)SSC Guru (87K reputation)SSC Guru (87K reputation)SSC Guru (87K reputation)

Group: General Forum Members
Points: 87005 Visits: 45267
Jeff Moden (7/4/2014)
Do you see any disparity between the ad-hoc code data-types and the table data-types that just might cause some unnecessary implicit conversions?


No, Char and varchar are fine together and lengths don't cause implicit conversion problems.

Gail Shaw
Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

We walk in the dark places no others will enter
We stand on the bridge and no one may pass


Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)

Group: General Forum Members
Points: 85639 Visits: 41082
GilaMonster (7/5/2014)
Jeff Moden (7/4/2014)
Do you see any disparity between the ad-hoc code data-types and the table data-types that just might cause some unnecessary implicit conversions?


No, Char and varchar are fine together and lengths don't cause implicit conversion problems.


I'll have to disagree with that especially on the personal experience level especially where the CHAR data-type is involved. Unfortunately, I can't demonstrate the "personal experience" portion of that because I had them fix it and moved on. I did, however, find an article a couple of months back that had code that demonstrated the problem. Now all I have to do is find the bloody thing. Pinch

I've bookmarked this post. When I find the article and can demonstrate the problem, I'll post back.

{EDIT} See my next post... I can't find the article and I can't recreate the problem so I have to retract this assertion until I can offer proof in code. My apologies, folks.

--Jeff Moden

RBAR is pronounced ree-bar and is a Modenism for Row-By-Agonizing-Row.
First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column.
If you think its expensive to hire a professional to do the job, wait until you hire an amateur. -- Red Adair

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search