By default, when a compound index is created in Microsoft Access, no
individual indexes are assigned to the fields included in the compound
index. This behavior is by design.
For the query optimizer to use an index, you must use a comparison of
either the first field in the compound index or the first field and any
number of adjacent fields (up to 10) that make up the compound index. You
must query the indexed fields in the order that they appear in the
Indexes dialog box, beginning with the first indexed field and continuing with adjacent fields.
NOTE: This principle also applies to using criteria with the
Find method in Visual Basic for Applications.
For example, consider a table (T1) that has three fields: key_part1,
key_part2, and key_part3. If there is a composite index created on these
three fields and all fields are the primary key, then the following SQL statement does not use the index, because the first field, key_part1, is not being used.
SELECT * FROM T1 WHERE key_part2 = <value>
Neither does the following SQL Statement make use of the index. Although key_part1 is referred to, key_part1 and key_part3 are not adjacent fields.
SELECT * FROM T1 WHERE key_part1 = <value> AND key_part3 = <value>
However, each of the following three SQL statements will use the index
because they each include the first field, or the first field and one or
more adjacent fields of the composite index:
SELECT * FROM T1 WHERE key_part1 = <value>
SELECT * FROM T1 WHERE key_part1 = <value> AND key_part2 = <value>
SELECT * FROM T1 WHERE key_part1 = <value> AND key_part2 = <value> AND key_part3 = <value>
The above fields are not prohibited from having individual indexes on them. Individual indexes can be built for each field, allowing comparisons on those fields with index searches. Be aware, however, that indexes can take up as much (or more) space than the data.