ACC2000: How to Use Visual Basic for Applications to Check for Duplicate Values in a Field (209479)



The information in this article applies to:

  • Microsoft Access 2000

This article was previously published under Q209479
Moderate: Requires basic macro, coding, and interoperability skills.

This article applies to a Microsoft Access database (.mdb) and to a Microsoft Access project (.adp).

SUMMARY

This article demonstrates how to create a Visual Basic for Applications procedure that uses the DLookup() function to check for duplicate values in a field before you leave that field.

MORE INFORMATION

Microsoft Access provides automatic checking for duplicate values in a field that has been designated as the primary key. However, this check occurs after all fields for a record have been entered, just before the record is committed to the database. The following sample code will perform a duplicate check as the data is entered in a field. To check for duplicate values in a field as you enter the data, follow these steps:

CAUTION: If you follow the steps in this example, you modify the sample database Northwind.mdb. You may want to back up the Northwind.mdb file and follow these steps on a copy of the database.

  1. Start Microsoft Access and open the sample database Northwind.mdb.
  2. In the Database window, click Forms under Objects, and then click New.
  3. In the New Form dialog box, click Auto: Columnar and then select Customers to indicate the table where the form's data comes from.
  4. View the form in Design view, and click the CustomerID text box.
  5. If the property sheet is not already visible, click Properties on the View menu.
  6. In the Before Update event, select [Event Procedure] to run just before you update the data in the CustomerID field.
  7. On the View menu, click Code. Type or paste in the following code:
    Private Sub CustomerID_BeforeUpdate(Cancel As Integer)
    
       Dim x As Variant
    
       x = DLookup("[CustomerID]", "Customers", "[CustomerID]= '" _
         & Forms!newcustomers!CustomerID & "'")
    
       On Error GoTo CustID_Err
    
       If Not IsNull(x) Then
          Beep
          MsgBox "That value already exists", vbOKOnly, "Duplicate Value"
          Cancel = True
       End If
    
    CustID_Exit:
       Exit Sub
    
    CustID_Err:
       MsgBox Error$
       Resume CustID_Exit
       
    End Sub
    					
  8. Close the Visual Basic Editor and save the form as NewCustomers.
  9. On the View menu, click Form View. Make a note of the value of the current CustomerID.
  10. On the Records menu, click Data Entry to add a new record.
  11. Enter the value of the earlier noted CustomerID.

    The message box with your message appears and the cursor is returned to the CustomerID field.

REFERENCES

For more information about duplicate values in a field, click Microsoft Access Help on the Help menu, type duplicate values in the Office Assistant or the Answer Wizard, and then click Search to view the topic.

Modification Type:MinorLast Reviewed:10/11/2006
Keywords:kbhowto kbusage KB209479