How To Check Table Field Index Property = Yes (No Duplicates) (1 Viewer)

q582gmzhi1

New member
Local time
Today, 01:50
Joined
Feb 26, 2020
Messages
3
Hi,

I am trying to find a way to check if an existing Field in a Table, Indexed Property value = Yes (No Duplicates), before running some imports via VBA.

I don't know what happened but noticed the field index Property had changed from Yes (No Duplicates) to Yes (Duplicates OK) and it caused me a slight headache sorting it out.

Just wanted to check before future imports takes place that the property had not changed from Yes (No Duplicates).

Many thanks in advance...
 

arnelgp

..forever waiting... waiting for jellybean!
Local time
Today, 08:50
Joined
May 7, 2009
Messages
19,231
you can create a public function in a module, passing the tablename and fieldname to test if it has a unique index:
Code:
Public Function IsIndexUnique(strTable As String, strField As String) As Boolean
    
    On Error Resume Next
    
    Dim td As DAO.TableDef
    Dim idx As DAO.Index
    Dim db As DAO.Database
    
    Set db = CurrentDb
    Set td = db.TableDefs(strTable)
    If Err Then
        Set db = Nothing
        Exit Function
    End If
    For Each idx In td.Indexes
        If idx.Fields = "+" & strField Then
            IsIndexUnique = idx.Unique
            Exit For
        End If
    Next
    Set idx = Nothing
    Set td = Nothing
    Set db = Nothing
End Function
 

ebs17

Well-known member
Local time
Today, 02:50
Joined
Feb 7, 2020
Messages
1,934
I don't know what happened but noticed the field index Property had changed from Yes (No Duplicates) to Yes (Duplicates OK)
If someone else changes the table definitions without qualification, this is a very problematic case. This should be observed and prevented.

Eberhard
 

The_Doc_Man

Immoderate Moderator
Staff member
Local time
Yesterday, 19:50
Joined
Feb 28, 2001
Messages
27,138
@q582gmzhi1

The question is, if you set it to "No Dups" then how would it get unset? Do you allow folks unrestricted access to your tables? Do a search on "securing a database" to see articles on hiding the ribbon, tables, queries, and other objects. Otherwise you are running in quicksand.
 

q582gmzhi1

New member
Local time
Today, 01:50
Joined
Feb 26, 2020
Messages
3
you can create a public function in a module, passing the tablename and fieldname to test if it has a unique index:
Code:
Public Function IsIndexUnique(strTable As String, strField As String) As Boolean
   
    On Error Resume Next
   
    Dim td As DAO.TableDef
    Dim idx As DAO.Index
    Dim db As DAO.Database
   
    Set db = CurrentDb
    Set td = db.TableDefs(strTable)
    If Err Then
        Set db = Nothing
        Exit Function
    End If
    For Each idx In td.Indexes
        If idx.Fields = "+" & strField Then
            IsIndexUnique = idx.Unique
            Exit For
        End If
    Next
    Set idx = Nothing
    Set td = Nothing
    Set db = Nothing
End Function
Thanks works great. Now have several checks in place.
 

q582gmzhi1

New member
Local time
Today, 01:50
Joined
Feb 26, 2020
Messages
3
@q582gmzhi1

The question is, if you set it to "No Dups" then how would it get unset? Do you allow folks unrestricted access to your tables? Do a search on "securing a database" to see articles on hiding the ribbon, tables, queries, and other objects. Otherwise you are running in quicksand.
There is only me that uses the db, I can only think I must have unset it accidentally when doing some tweeks. Now the above code is in place to check I don't accidentally change it again.
 

Users who are viewing this thread

Top Bottom