Wrox Programmer Forums
|
SQL Server 2000 General discussion of Microsoft SQL Server -- for topics that don't fit in one of the more specific SQL Server forums. version 2000 only. There's a new forum for SQL Server 2005.
Welcome to the p2p.wrox.com Forums.

You are currently viewing the SQL Server 2000 section of the Wrox Programmer to Programmer discussions. This is a community of software programmers and website developers including Wrox book authors and readers. New member registration was closed in 2019. New posts were shut off and the site was archived into this static format as of October 1, 2020. If you require technical support for a Wrox book please contact http://hub.wiley.com
 
Old March 30th, 2004, 03:12 PM
Friend of Wrox
 
Join Date: Jun 2003
Posts: 1,998
Thanks: 0
Thanked 3 Times in 3 Posts
Default Clustered Index Scan

Hello,

I'm looking at the estimated execution plan for one of my stored procedures. I've got a Clustered Index Scan occuring, where the number of rows exceeds 1800. The Clustered PK on this table is an ID field that is an identity with the data type of int.

Does anybody know how to increase performance on this table? I'm being told by the DBA's that I have to fix the table scan.

Thanks,

Brian
__________________
Brian
 
Old April 1st, 2004, 12:27 PM
Registered User
 
Join Date: Apr 2004
Posts: 9
Thanks: 0
Thanked 0 Times in 0 Posts
Default

I think you might want to increase performance on select queries.
Put a non clustered index on a column based on the value of which
most of your select queries are running.

I hope this will increase your performance of select queries.


Puneet
 
Old April 1st, 2004, 04:03 PM
Friend of Wrox
 
Join Date: Jun 2003
Posts: 839
Thanks: 0
Thanked 1 Time in 1 Post
Default

A clustered index scan isn't altogether bad. It is, after all, a scan of your data (the clustered index is where your data columns are). If you execute a query which says, "Give me all rows where this condition is true", you must of necessity look at each row in turn to see if the row matches the condition.

Now, if you do this search a lot, you can place an index on the column(s) involved in the search which might speed things up. This really only holds true if the column data you are testing has a reasonable level of specificity. The less specific the values are, the less utility an index will give you. For example, if your query condition is something like "WHERE Gender='M'" an index on this column isn't likely to do you much good, and in fact may actually be slower than the clustered index scan. There are just too many duplicates, so scanning may actually be faster than bouncing back between index and data. And, of course, the presence of the index will slow down updates/inserts/deletes.

On the other hand, if your condition is something like "WHERE OrderDate > '1/1/2004'" then you may gain a significant improvement with the index, especially if you have 2 zillion orders dated before this year. The table scan will require reading all those rows, whereas the index will allow you to find this year's data quickly.

Generally (very generally) speaking, it is a good idea to place an index on those columns involved in heavy selections, or on those columns involved in JOINs. Note that the presence of a FOREIGN KEY or UNIQUE constraint already implies the existence of an index.

You may consider creating what's called a "covering index" on those columns involved in SELECTs, JOINs, and/or WHERE clauses. A covering index contains all the columns in these clauses. If there are a lot of such columns, forget it, as the overhead of the index will outweigh the benefits. A covering index can give you significant performance benefit, because the conditions of the clause(s) can be satisfied entirely from the index, and the data (clustered index) never has to be referred to.

It may or not be a good idea to create the clustered index on the identity ID column. Doing so means your data almost always isn't in the right order, and if you insert rows a lot (though with only 1800 rows this is unlikely to be the case) you can end up with a "hot spot" right at the end of the clustered index, where all the activity is taking place. If there is a more "natural" key, it might be better to place the index on that. A lot depends on your situation, though, since if the ID is used a lot in JOINs, the clustered index may in fact be better placed on it.

There are no hard and fast rules on this performance tuning stuff - it all depends on your unique situation. Perhaps if you post some more details about the table structures and the offending query, we might be able to offer additional insights...

Jeff Mason
Custom Apps, Inc.
www.custom-apps.com
 
Old April 2nd, 2004, 02:07 PM
Friend of Wrox
 
Join Date: Jun 2003
Posts: 1,998
Thanks: 0
Thanked 3 Times in 3 Posts
Default

That's what I thought, I just wanted to verify this. Thanks for your help.
 
Old April 6th, 2009, 06:25 AM
Authorized User
 
Join Date: Sep 2007
Posts: 31
Thanks: 0
Thanked 0 Times in 0 Posts
Default

Quote:
Originally Posted by Jeff Mason View Post
A clustered index scan isn't altogether bad. It is, after all, a scan of your data (the clustered index is where your data columns are). If you execute a query which says, "Give me all rows where this condition is true", you must of necessity look at each row in turn to see if the row matches the condition.

Now, if you do this search a lot, you can place an index on the column(s) involved in the search which might speed things up. This really only holds true if the column data you are testing has a reasonable level of specificity. The less specific the values are, the less utility an index will give you. For example, if your query condition is something like "WHERE Gender='M'" an index on this column isn't likely to do you much good, and in fact may actually be slower than the clustered index scan. There are just too many duplicates, so scanning may actually be faster than bouncing back between index and data. And, of course, the presence of the index will slow down updates/inserts/deletes.

On the other hand, if your condition is something like "WHERE OrderDate > '1/1/2004'" then you may gain a significant improvement with the index, especially if you have 2 zillion orders dated before this year. The table scan will require reading all those rows, whereas the index will allow you to find this year's data quickly.

Generally (very generally) speaking, it is a good idea to place an index on those columns involved in heavy selections, or on those columns involved in JOINs. Note that the presence of a FOREIGN KEY or UNIQUE constraint already implies the existence of an index.

You may consider creating what's called a "covering index" on those columns involved in SELECTs, JOINs, and/or WHERE clauses. A covering index contains all the columns in these clauses. If there are a lot of such columns, forget it, as the overhead of the index will outweigh the benefits. A covering index can give you significant performance benefit, because the conditions of the clause(s) can be satisfied entirely from the index, and the data (clustered index) never has to be referred to.

It may or not be a good idea to create the clustered index on the identity ID column. Doing so means your data almost always isn't in the right order, and if you insert rows a lot (though with only 1800 rows this is unlikely to be the case) you can end up with a "hot spot" right at the end of the clustered index, where all the activity is taking place. If there is a more "natural" key, it might be better to place the index on that. A lot depends on your situation, though, since if the ID is used a lot in JOINs, the clustered index may in fact be better placed on it.

There are no hard and fast rules on this performance tuning stuff - it all depends on your unique situation. Perhaps if you post some more details about the table structures and the offending query, we might be able to offer additional insights...

Jeff Mason
Custom Apps, Inc.
www.custom-apps.com
that helped me much thanks a lot
 
Old June 7th, 2010, 11:35 AM
Registered User
 
Join Date: Dec 2006
Posts: 2
Thanks: 0
Thanked 0 Times in 0 Posts
Default

Quote:
Originally Posted by Jeff Mason View Post
A clustered index scan isn't altogether bad. It is, after all, a scan of your data (the clustered index is where your data columns are). If you execute a query which says, "Give me all rows where this condition is true", you must of necessity look at each row in turn to see if the row matches the condition.

Now, if you do this search a lot, you can place an index on the column(s) involved in the search which might speed things up. This really only holds true if the column data you are testing has a reasonable level of specificity. The less specific the values are, the less utility an index will give you. For example, if your query condition is something like "WHERE Gender='M'" an index on this column isn't likely to do you much good, and in fact may actually be slower than the clustered index scan. There are just too many duplicates, so scanning may actually be faster than bouncing back between index and data. And, of course, the presence of the index will slow down updates/inserts/deletes.

On the other hand, if your condition is something like "WHERE OrderDate > '1/1/2004'" then you may gain a significant improvement with the index, especially if you have 2 zillion orders dated before this year. The table scan will require reading all those rows, whereas the index will allow you to find this year's data quickly.

Generally (very generally) speaking, it is a good idea to place an index on those columns involved in heavy selections, or on those columns involved in JOINs. Note that the presence of a FOREIGN KEY or UNIQUE constraint already implies the existence of an index.

You may consider creating what's called a "covering index" on those columns involved in SELECTs, JOINs, and/or WHERE clauses. A covering index contains all the columns in these clauses. If there are a lot of such columns, forget it, as the overhead of the index will outweigh the benefits. A covering index can give you significant performance benefit, because the conditions of the clause(s) can be satisfied entirely from the index, and the data (clustered index) never has to be referred to.

It may or not be a good idea to create the clustered index on the identity ID column. Doing so means your data almost always isn't in the right order, and if you insert rows a lot (though with only 1800 rows this is unlikely to be the case) you can end up with a "hot spot" right at the end of the clustered index, where all the activity is taking place. If there is a more "natural" key, it might be better to place the index on that. A lot depends on your situation, though, since if the ID is used a lot in JOINs, the clustered index may in fact be better placed on it.

There are no hard and fast rules on this performance tuning stuff - it all depends on your unique situation. Perhaps if you post some more details about the table structures and the offending query, we might be able to offer additional insights...

Jeff Mason
Custom Apps, Inc.
www.custom-apps.com
A very clear and easy to understand explanation. Thankyou.
I shall be quoting this when working with our junior programmers





Similar Threads
Thread Thread Starter Forum Replies Last Post
Page splits - Clustered vs Non-Clustered Index carumuga SQL Server 2005 3 October 20th, 2008 04:23 AM
Clustered PK Constr fails to create on big table kapluni SQL Server 2000 5 November 23rd, 2005 06:27 PM
Question about clustered indexes patwadd SQL Server 2000 1 July 15th, 2005 05:01 AM
Size of Clustered Index MikeSchnell SQL Server 2000 0 May 7th, 2004 02:34 PM
Virus Scan koneruvijay VS.NET 2002/2003 0 February 24th, 2004 03:35 AM





Powered by vBulletin®
Copyright ©2000 - 2020, Jelsoft Enterprises Ltd.
Copyright (c) 2020 John Wiley & Sons, Inc.