Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Hits and Misses


Hits and Misses

Author
Message
Mike Metcalf
Mike  Metcalf
SSChasing Mays
SSChasing Mays (655 reputation)SSChasing Mays (655 reputation)SSChasing Mays (655 reputation)SSChasing Mays (655 reputation)SSChasing Mays (655 reputation)SSChasing Mays (655 reputation)SSChasing Mays (655 reputation)SSChasing Mays (655 reputation)

Group: General Forum Members
Points: 655 Visits: 53
Comments posted to this topic are about the content posted at http://www.sqlservercentral.com/columnists/mmetcalf/hitsandmisses.asp
Jamie Thomson
Jamie Thomson
SSC Eights!
SSC Eights! (973 reputation)SSC Eights! (973 reputation)SSC Eights! (973 reputation)SSC Eights! (973 reputation)SSC Eights! (973 reputation)SSC Eights! (973 reputation)SSC Eights! (973 reputation)SSC Eights! (973 reputation)

Group: General Forum Members
Points: 973 Visits: 188

Mike,

That was a great article and told me somethnig I didn't know. Thanks.

I'm interested in one thing you said though: "If you are seeing a high proportion of misses as opposed to hits then you should consider going back and checking that all objects are being called with the correct owner and also that they are being passed in the same case as they were originally created."

What in your opinion (or anyone else's opinion) would constitute "a high proportion of misses as opposed to hits"? We're talking ratios here aren't we? At what ratio do I need to start worrying?

As an aside, what is SQL DevCon 2005? I live in London and have never heard of it.

Thanks again. Cracking article.



Jamie Thomson
http://sqlblog.com/blogs/jamie_thomson
Andy in Pembs
Andy in Pembs
SSC-Enthusiastic
SSC-Enthusiastic (129 reputation)SSC-Enthusiastic (129 reputation)SSC-Enthusiastic (129 reputation)SSC-Enthusiastic (129 reputation)SSC-Enthusiastic (129 reputation)SSC-Enthusiastic (129 reputation)SSC-Enthusiastic (129 reputation)SSC-Enthusiastic (129 reputation)

Group: General Forum Members
Points: 129 Visits: 40

Supurb article Mike, cheers.

As for Devcon Jamie, see http://www.devweek.com/ its probabbly he bigest in the UK and generally the one to go for, if you only go to one.


Chris Hedgate
Chris Hedgate
SSCommitted
SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)

Group: General Forum Members
Points: 1651 Visits: 7
I agree with the others, very interesting article and something that I did not know about. However, I am not quite sure that everything is fully correct in the article, or at least I am not sure what conclusions to draw from it. First off, I could not trace any SP:CacheMiss events when only the casing of the parameter(s) to procedures changed. No matter how I wrote them I never got a cache miss if that was the only change in the call to the procedure. And since only the procedure name is stored with the cache object (and used when looking for a cached plan) I can not see how it could work differently.

Furthermore, I do not think that the plans are actually recompiled, even though there is sometimes a SP:CacheMiss (when using incorrect case for procedure name). You wrote that even if a procedure is executed using incorrect casing it is still stored in the cache with the correct casing (the way it was once created using CREATE PROC). You can see this in syscacheobjects, where the sql column stores the procedure name in correct casing, so we know that the name is looked up. From this I draw the conclusion that the same thing happens when you later on call the procedure, using incorrect case. The SP:CacheMiss we are seeing is for the cached object with the incorrect casing. Since none can exist (it will always be correctly cased) we get a cache miss. This is of course good, since otherwise there would be different plans for the same procedure. Note that if the server would be using case-sensitive settings then there could be two procs with the same name, only using different casing, and they should of course have different plans.

After the cache miss SQL Server looks for a cached plan stored with the correctly cased procedure name (which it now looks up). If one is found then that plan is used. You can see this by watching the value in column UseCounts incrementing one step each time the procedure is executed, irregardless of whether or not the name is correctly cased and we are seeing an SP:CacheMiss or not. Also, in SQL Profiler, add the data column ObjectName to the output. Then you will see what the cache lookup is actually missing. Clear the cache (using DBCC FREEPROCCACHE) and then execute the procedure using incorrect casing for the proc name. In Profiler you will see two cache misses, first for the incorrectly cased name, next for the correctly cased name. Since this is the first time the proc is executed (after clearing the cache) this is the behaviour we could expect. After this there is an SP:CacheInsert event, which of copurse inserts that plan to the cache using the correctly cased name of the proc.

At least this is the conclusions I draw from experimenting a little with this, but I might be wrong here. Otherwise, in summary I think the implications of this problem is even smaller than it would be with a lot of recompiles, although I for one definitely agree that any small thing that helps performance is always a good thing. Like you said, if SQL Server is spending (any) time doing anything that it would not have needed to if we only coded correctly, then we should not be happy with ourselves.

Thanks again for the article and for teaching me something new.

--
Chris Hedgate http://www.hedgate.net/
Contributor to the Best of SQL Server Central volumes
Articles: http://www.sqlservercentral.com/columnists/chedgate/
David.Poole
David.Poole
SSCarpal Tunnel
SSCarpal Tunnel (4.6K reputation)SSCarpal Tunnel (4.6K reputation)SSCarpal Tunnel (4.6K reputation)SSCarpal Tunnel (4.6K reputation)SSCarpal Tunnel (4.6K reputation)SSCarpal Tunnel (4.6K reputation)SSCarpal Tunnel (4.6K reputation)SSCarpal Tunnel (4.6K reputation)

Group: General Forum Members
Points: 4640 Visits: 3187
If the cache is case sensitive then surely this also has implications for sp_executesql?

LinkedIn Profile

Newbie on www.simple-talk.com
Chris Hedgate
Chris Hedgate
SSCommitted
SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)

Group: General Forum Members
Points: 1651 Visits: 7
Very good point David. And it is in fact much worse for sp_executesql, since there it means that a new plan must be compiled (and cached) in order to execute a prepared statement that is exactly the same as a previous one except for casing. The reason is that for statements it is the entire statement that is matched (with a hashing function) to the one stored in the cache. For procs it is only the proc name, so SQL Server can much easier gather the correctly cased name (in fact it already has got it since it needed the proc definition to compile it) for storing. For a statement it would need to gather (and replace) all the object names used in the statement, plus use one case for all keywords. Using the following test script you can see that it does not do that.

----------------------------------

use northwind

dbcc freeproccache

declare @sql1 nvarchar(500)
set @sql1 = N'select * from dbo.Orders'

declare @sql2 nvarchar(500)
set @sql2 = N'select * FROM dbo.Orders'

exec sp_executesql @sql1
exec sp_executesql @sql2

exec sp_executesql @sql1
exec sp_executesql @sql2

exec sp_executesql @sql1
exec sp_executesql @sql2

-- Note the two plans for the same statement only differing in case for the keyword FROM
-- Also note how UseCounts show each one is used three times
-- Finally, also note that the two plans are stored in different hash buckets, so they cannot be matched of course
select * from master..syscacheobjects
----------------------------------

--
Chris Hedgate http://www.hedgate.net/
Contributor to the Best of SQL Server Central volumes
Articles: http://www.sqlservercentral.com/columnists/chedgate/
Antares686
Antares686
SSCrazy Eights
SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)

Group: Moderators
Points: 8868 Visits: 780

First off it is a very good article and pointed out something I never noticed before.

But I do agree with Chris.

Only when the name of the executing SP was different in case did I see a CacheMiss. When the name of the parameters were not exactly cased the same it made no difference.

And I never saw a recompile occurr or a new CacheInsert. I just saw a CacheMiss. Of course this still means a performance degrade on high transaction systems.

As for the question earlier about how many would you say before you consider it bad. I would suggest any, you just simple want to avoid as much unneeded work on SQLs part as much as possible.





Antares686
Antares686
SSCrazy Eights
SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)

Group: Moderators
Points: 8868 Visits: 780
Also tested the same things with SQL 7 and it behaved differently with this. Case made no difference on the third or forth run afterwards. So is this specific to 2000?



noeld
noeld
SSCertifiable
SSCertifiable (7.1K reputation)SSCertifiable (7.1K reputation)SSCertifiable (7.1K reputation)SSCertifiable (7.1K reputation)SSCertifiable (7.1K reputation)SSCertifiable (7.1K reputation)SSCertifiable (7.1K reputation)SSCertifiable (7.1K reputation)

Group: General Forum Members
Points: 7082 Visits: 2048

I have a friend who develops on case-sensitive servers and his opinion is that what he develops will also work on case-insensitive ones. He will love to see this one.

BTW Thanks for the article (Another trick for my bag)




* Noel
DCPeterson
DCPeterson
Ten Centuries
Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)

Group: General Forum Members
Points: 1199 Visits: 432

First off, thank you for the article. It isn't very often that I get to read an article that really teaches me something new and explains something that has left me totally puzzled in the past. That said, I think Chris' analysis is probably correct. I saw cache misses, but not recompiles; and the capitalization of parameter names apparently doesn't have any effect on this.

I had noticed several years ago that one of our applications tended to generate many cache misses, but not a lot of recompiles. Adding more RAM to the system helped overall performance, but not this particular situation. I could never come up with a plausible explanation, this fits the bill.

Thanks again for sharing this bit of information.



/*****************

If most people are not willing to see the difficulty, this is mainly because, consciously or unconsciously, they assume that it will be they who will settle these questions for the others, and because they are convinced of their own capacity to do this. -Friedrich August von Hayek



*****************/
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