July 17, 2013 at 2:07 am
Hi,
I've been doing some monitoring on one of our SSRS servers and have picked up a dead lock that occurs every morning at 2am, the victim and the deadlocking process are both the system created stored procedure 'dbo.CleanExpiredServerParameters' in the ReportServer database.
I can see that this is removing expired parameters but what I am having trouble determining is what is calling this, we have nothing running at 2am so this must mean that the SSRS instance itself is running this, does anyone know about this procedure? Or how I may be able to resolve the deadlock.
The procedure is running the following code;
CREATE PROCEDURE [dbo].[CleanExpiredServerParameters]
@ParametersCleaned INT OUTPUT
AS
DECLARE @now as DATETIME
SET @now = GETDATE()
DELETE FROM [dbo].[ServerParametersInstance]
WHERE ServerParametersID IN
(SELECT TOP 20 ServerParametersID FROM [dbo].[ServerParametersInstance]
WHERE Expiration < @now
)
SET @ParametersCleaned = @@ROWCOUNT
I've not had much luck in finding anything about it.
Any help you can be would be gratefully appreciated.
Thanks,
Nic
July 17, 2013 at 2:23 am
Run a trace when the deadlock occurs. In the trace you can specify the hostname, loginname, NT domain name, etc. to get more information about the connections involved in the deadlock. Hopefully this will give you more information abouw who/what is execution the statements.
July 17, 2013 at 2:28 am
Could you rewrite the delete statement to:
DELETE TOP (20) FROM [dbo].[ServerParametersInstance]
WHERE Expiration < @now
This will prevent the query to simultaneously read and delete from the same table.
July 17, 2013 at 2:54 am
HanShi (7/17/2013)
Could you rewrite the delete statement to:
DELETE TOP (20) FROM [dbo].[ServerParametersInstance]
WHERE Expiration < @now
This will prevent the query to simultaneously read and delete from the same table.
Hi,
Thanks for the reply.
I did think about this, but it's (as far as I can tell) an internal SSRS procedure and I'm a little nervous about messing with it, although if it works, it works I guess.
As for the host, this is coming from the SSRS instance itself.
I'll keep digging for more info but I think I'll try the modified procedure to see if I can lighten the load a little.
July 17, 2013 at 3:06 am
HanShi (7/17/2013)
Could you rewrite the delete statement to:
DELETE TOP (20) FROM [dbo].[ServerParametersInstance]
WHERE Expiration < @now
This will prevent the query to simultaneously read and delete from the same table.
SQL Server already does this for you. Look at the execution plan, specifically the eager spool.
Having said that, this is an odd little stored procedure. In this article, MS says "If you have to use TOP to delete rows in a meaningful chronological order, you must use TOP together with ORDER BY in a subselect statement." I think MS forgot to put the ORDER BY into the subselect - in which case, your version will achieve the same result with only one read instead of two.
For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
July 17, 2013 at 3:51 am
Thanks for the reply Chris.
I see what you mean, I've modified the query, the execution plans show a marked performance increase which is good.
Guess I'll just see what happens this evening, I just wish I knew what exactly was calling this, I'm guessing it's something internal to SSRS and it's doing routine clean up of expired data, it just seems odd that this occurs every evening at 2am.
Nic
July 18, 2013 at 3:46 am
HanShi (7/17/2013)
Could you rewrite the delete statement to:
DELETE TOP (20) FROM [dbo].[ServerParametersInstance]
WHERE Expiration < @now
This will prevent the query to simultaneously read and delete from the same table.
Hi,
This has resolved the deadlock, thank you both for your help with this.
Nic
Viewing 7 posts - 1 through 6 (of 6 total)
You must be logged in to reply to this topic. Login to reply