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


An Un-indexed Foreign Key Gotcha


An Un-indexed Foreign Key Gotcha

Author
Message
TheSQLGuru
TheSQLGuru
SSCertifiable
SSCertifiable (7K reputation)SSCertifiable (7K reputation)SSCertifiable (7K reputation)SSCertifiable (7K reputation)SSCertifiable (7K reputation)SSCertifiable (7K reputation)SSCertifiable (7K reputation)SSCertifiable (7K reputation)

Group: General Forum Members
Points: 6989 Visits: 8389
sqlpro (11/9/2009)
thanks for the reply. probably i misunderstood but following is the link i got my understanding from.its here http://www.informit.com/library/content.aspx?b=STY_Sql_Server_7&seqNum=145



In general, nonclustered indexes (and the associated bookmark lookup to the base table) will be used only if the query is estimated to hit between 0 and perhaps as much as 2 percent of the total rows. This is a surprisingly low percentage to most people. Often, and certainly the case in my example where I explicitely stated there was exactly one FK child row per parent in a billion row table, FK children tables have VERY few rows per parent key and an index WILL be beneficial for lookups/joins.

Best,

Kevin G. Boles
SQL Server Consultant
SQL MVP 2007-2012
TheSQLGuru at GMail
mcvilbar
mcvilbar
SSC-Enthusiastic
SSC-Enthusiastic (120 reputation)SSC-Enthusiastic (120 reputation)SSC-Enthusiastic (120 reputation)SSC-Enthusiastic (120 reputation)SSC-Enthusiastic (120 reputation)SSC-Enthusiastic (120 reputation)SSC-Enthusiastic (120 reputation)SSC-Enthusiastic (120 reputation)

Group: General Forum Members
Points: 120 Visits: 120
I've been realizing that creating a non-clustered index on the foreign key is quite a very good idea. Nice article, very informative and interesting. :-)
sqlpro
sqlpro
Old Hand
Old Hand (387 reputation)Old Hand (387 reputation)Old Hand (387 reputation)Old Hand (387 reputation)Old Hand (387 reputation)Old Hand (387 reputation)Old Hand (387 reputation)Old Hand (387 reputation)

Group: General Forum Members
Points: 387 Visits: 143
that makes sense. thanks for correcting that TheSQLGuru :-)



denise.crabtree
denise.crabtree
Valued Member
Valued Member (62 reputation)Valued Member (62 reputation)Valued Member (62 reputation)Valued Member (62 reputation)Valued Member (62 reputation)Valued Member (62 reputation)Valued Member (62 reputation)Valued Member (62 reputation)

Group: General Forum Members
Points: 62 Visits: 81
I couldn't resist -- I wanted to query to find them. Didn't read all replies first. So here is my simple query to find a table without an index on a foreign key.

If FK exists and column is in NO index -- then it will list out. Could be refined more. (exact order for multiple column FK match exact order for indexes )

-----------------------------------------------------------------------
-- Find a list of Foreign Keys that are not indexed
--
-- Created 11-09-2009 Denise Crabtree
-----------------------------------------------------------------------
-----------------------------------------------------------------------
SELECT
object_name(parent_object_id) [FK table]
,object_name(referenced_object_id) [References this Table]
,object_name(constraint_object_id) [Foreign Key Name]
,sys.columns.name [ChildTable Column]

FROM sys.foreign_key_columns
INNER JOIN sys.columns
ON sys.foreign_key_columns.parent_object_id = sys.columns.object_id
AND sys.foreign_key_columns.Parent_column_id = sys.columns.column_id

LEFT OUTER JOIN sys.index_columns
ON sys.foreign_key_columns.parent_object_id = sys.index_columns.object_id
AND sys.foreign_key_columns.Parent_column_id = sys.index_columns.column_id

WHERE
sys.index_columns.object_id is null
TheSQLGuru
TheSQLGuru
SSCertifiable
SSCertifiable (7K reputation)SSCertifiable (7K reputation)SSCertifiable (7K reputation)SSCertifiable (7K reputation)SSCertifiable (7K reputation)SSCertifiable (7K reputation)SSCertifiable (7K reputation)SSCertifiable (7K reputation)

Group: General Forum Members
Points: 6989 Visits: 8389
See the earlier reply by richardd. It has a link to a script by Paul Nielson that not only identifies FKs missing indexes but will actually generate CREATE INDEX scripts for them (IIRC).

Best,

Kevin G. Boles
SQL Server Consultant
SQL MVP 2007-2012
TheSQLGuru at GMail
SQLRNNR
SQLRNNR
SSC-Insane
SSC-Insane (22K reputation)SSC-Insane (22K reputation)SSC-Insane (22K reputation)SSC-Insane (22K reputation)SSC-Insane (22K reputation)SSC-Insane (22K reputation)SSC-Insane (22K reputation)SSC-Insane (22K reputation)

Group: General Forum Members
Points: 22930 Visits: 18262
Good Article with useful info. Thanks



Jason AKA CirqueDeSQLeil
I have given a name to my pain...
MCM SQL Server, MVP


SQL RNNR

Posting Performance Based Questions - Gail Shaw

mister_zed
mister_zed
Grasshopper
Grasshopper (18 reputation)Grasshopper (18 reputation)Grasshopper (18 reputation)Grasshopper (18 reputation)Grasshopper (18 reputation)Grasshopper (18 reputation)Grasshopper (18 reputation)Grasshopper (18 reputation)

Group: General Forum Members
Points: 18 Visits: 16
The indexed FKs have nothing to do with performance; increased performance MIGHT be a side-effect, but - as you point out - it might as well not be such an effect. The idea of indexing FK columns has to do with the locking mechanisms.

In order to be sure that you can delete a parent record you must also make sure that there are no children belonging to that parent. This can only be achieved by actually reading the child table(s). When you don't have any usable index on the child table, then you must read all records - and they get locked at the same time, just because they are part of an updating (read-write) transaction.

This is very common truth för many relational databases, including SQL Server, Oracle, Firebird and others, and it has so been since "ancient" times.


P.S. I thought it was common knowledge... ;-)
TheSQLGuru
TheSQLGuru
SSCertifiable
SSCertifiable (7K reputation)SSCertifiable (7K reputation)SSCertifiable (7K reputation)SSCertifiable (7K reputation)SSCertifiable (7K reputation)SSCertifiable (7K reputation)SSCertifiable (7K reputation)SSCertifiable (7K reputation)

Group: General Forum Members
Points: 6989 Visits: 8389
The indexed FKs have nothing to do with performance;


I think that is a bit of a stretch. There is almost always at least some performance benefit (often dramatic), both in efficient join/seek and in improved concurrency from reduced locking.

Best,

Kevin G. Boles
SQL Server Consultant
SQL MVP 2007-2012
TheSQLGuru at GMail
jswong05
jswong05
SSC-Enthusiastic
SSC-Enthusiastic (109 reputation)SSC-Enthusiastic (109 reputation)SSC-Enthusiastic (109 reputation)SSC-Enthusiastic (109 reputation)SSC-Enthusiastic (109 reputation)SSC-Enthusiastic (109 reputation)SSC-Enthusiastic (109 reputation)SSC-Enthusiastic (109 reputation)

Group: General Forum Members
Points: 109 Visits: 476
Please read Thomas Kyte's books. He wrote for Oracle but the principles about "transaction processing" and "locking" and "index" are the same.

When FK records can be fastly located by index, the transaction processing will be fast, that reduces required lock-time, hence improves performance. This applies to any records.

Jason
http://dbace.us
:-P
mister_zed
mister_zed
Grasshopper
Grasshopper (18 reputation)Grasshopper (18 reputation)Grasshopper (18 reputation)Grasshopper (18 reputation)Grasshopper (18 reputation)Grasshopper (18 reputation)Grasshopper (18 reputation)Grasshopper (18 reputation)

Group: General Forum Members
Points: 18 Visits: 16
I agree it's a bit of a stretch. :-)

My point was that indexing might have different purposes, optimizing search operations being just ONE of them.
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