View Single Post
  #2  
Old February 10th, 2005, 04:32 PM
Allen Browne
external usenet poster
 
Posts: n/a
Default

The limit is 32 indexes per table.

Some of the indexes may be hidden, i.e. they don't show up in the Indexes
dialog that you open in table design view. For example when you create a
relationship with enforced referential integrity, Access creates a hidden
index to manage it. Since you do that for all your foreign key fields, you
do not need to index your foreign keys. The code example below will list all
the indexes of a table for you.

Priority would be:
1. Primary key.
2. Hidden indexes required to manage the relationships.
3. Fields that require an index to enforce a rule (e.g. a field that must be
unique).
4. Fields that are frequently used for searching (criteria) or sorting
(order by).

If 2 fields appear to be equal on #4 above, give priority to the one that
has more possible values (e.g. not the yes/no field that has only 2 values).

A multi-field index is generally useful where you have a multi-field key, or
multi-field relation between 2 tables, or you need to enforce a multi-field
combination is unique. If you have one, don't index the *first* field in the
index: Access will use the multi-field index on the individual field.

Every index has to be maintained each time a record is added, modified, or
deleted. An excessive number of indexes can degrade performance if large
numbers of records are constantly changing. (There are even cases where you
might consider dropping indexes, performing a bulk append, and then
recreating the indexes again.)

While indexes do have a big impact on performance, they are not the only
factor. Other garbage in the newer versons of Access such as Name
AutoCorrect and Subdatasheets can degrade performance by an order of
magnitude if you don't turn them off. More info in Tony Toews' excellent
Access Performance FAQ at:
http://www.granite.ab.ca/access/performancefaq.htm

Here's the function that lists your hidden indexes:

Function ShowIndexes(strTable As String)
Dim db As DAO.Database
Dim tdf As DAO.TableDef
Dim ind As DAO.Index
Dim fld As DAO.Field

Set db = DBEngine(0)(0)
Set tdf = db.TableDefs(strTable)
For Each ind In tdf.Indexes
Debug.Print ind.Name, IIf(ind.Primary, "Primary", ""), _
IIf(ind.Foreign, "Foreign", ""), ind.Fields.Count
Debug.Print " Field(s): ";
For Each fld In ind.Fields
Debug.Print fld.Name;
Next
Debug.Print
Next

Set fld = Nothing
Set ind = Nothing
Set tdf = Nothing
Set db = Nothing
End Function


--
Allen Browne - Microsoft MVP. Perth, Western Australia.
Tips for Access users - http://allenbrowne.com/tips.html
Reply to group, rather than allenbrowne at mvps dot org.

"gmead7" wrote in message
...
I'm looking for guidance on Indexing in Access 2003.

Background: I'm working with an Access database shared over a network,
about 20 users and it has been split into FE / BE. I'm trying to milk all
the speed out of it that I can.

I view the Index table for my primary table and it looks full of indexed
fields. (I did this after trying to add an index to a field and getting
a
message that Access can't add index because there is too many).

1. What is the limit on number of indexes allowed on a table in Access
2003?

2. Is it possible to add an index within the view index table although
not
be able to add an index from design view of the table itself?

3. Any tips on prioritizing which should be indexed?

4. Tips on when to use a composite (combination) index or when not to?

thank you