INTELLIGENT WORK FORUMS
FOR COMPUTER PROFESSIONALS

Log In

Come Join Us!

Are you a
Computer / IT professional?
Join Tek-Tips Forums!
  • Talk With Other Members
  • Be Notified Of Responses
    To Your Posts
  • Keyword Search
  • One-Click Access To Your
    Favorite Forums
  • Automated Signatures
    On Your Posts
  • Best Of All, It's Free!

*Tek-Tips's functionality depends on members receiving e-mail. By joining you are opting in to receive e-mail.

Posting Guidelines

Promoting, selling, recruiting, coursework and thesis posting is forbidden.

Jobs

Using Replace function as Criteria for Dlookup

Using Replace function as Criteria for Dlookup

(OP)
Hello Everyone,

I am trying to guard against a person entering a duplicate value in a form. I needs this to be done programmatically and not thru the table properties. I can use a simple Dlookup to search for a duplicate value. However, I want to also try to account for typos where an extra space is included or where one is removed.

A Replace function should do this, but I am having difficulty creating a Dlookup function that incorporates it.

Here is what I need:
As the user enters a value, the program checks the field in the underlying table for a stored value matching the one being typed. If found, it disallows it. This means I have to compare a "trimmed" user-entry to a "trimmed" stored value.

Form Field = Cont_Group
Formula to incorporate = Replace([Cont_Group], " ", "")

How do I add the above formula to the Dlookup below to accomplish this?

If DLookup("Cont_Group", "tbl_Contract_Group_List", "Cont_Group = '" & Me.Cont_Group & "'") > 0 Then
Me.Undo
Cancel = True
GoTo exit_sub
Else
GoTo exit_sub
End If

Thanks in advance


RE: Using Replace function as Criteria for Dlookup

So are you attempting to remove spaces from both the entered value and the field you are comparing to?
I would try code like the following:

CODE --> vba

Dim strGroup as String
Dim strWhere as String
strGroup = Replace(Me.Cont_Group," ", "")
strWhere = "Cont_Group = '" & strGroup & "'"
If DCount("Cont_Group", "tbl_Contract_Group_List", strWhere) > 0 Then
    Me.Undo
    Cancel = True
    GoTo exit_sub
 Else
    GoTo exit_sub
End If 

Duane
Minnesota
Hook'D on Access
MS Access MVP 2001-2016

RE: Using Replace function as Criteria for Dlookup

(OP)
Hi Dhookom,

I made an error, which you caught. I meant to specify Dcount instead of Dlookup. Thanks for that. However, there is an issue with the code you provided. The code should compare what the user is currently typing against what is stored. To account for typos, the code should remove all spaces from both entries. If you look at your code, you will see that your code only removes spaces from the entry being typed. This means that it will always treat the two values as being different and allow the new entry.

I have tried variations of the following. Either it produces a syntax error or does not read the data correctly.

Dim strGroup As String
Dim strValue As String
strGroup = Replace(Me.Cont_Group, " ", "") ' user entry
strValue = Replace(Cont_Group, " ", "")

If DCount("Cont_Group", "tbl_Contract_Group_List", strValue = strGroup) > 0 Then
Me.Undo
Cancel = True
GoTo exit_sub
Else
GoTo exit_sub
End If

Any Ideas?

RE: Using Replace function as Criteria for Dlookup

That's the reason I asked the question about removing spaces. I had no idea if the field allowed spaces. Please use TGML to mark your code so it is easier to read.
Try:

CODE --> vba

Dim strGroup as String
Dim strWhere as String
strGroup = Replace(Me.Cont_Group," ", "")
strWhere = "Replace(Cont_Group,' ','') = '" & strGroup & "'"
If DCount("Cont_Group", "tbl_Contract_Group_List", strWhere) > 0 Then
    Me.Undo
    Cancel = True
    GoTo exit_sub
 Else
    GoTo exit_sub
End If 

Duane
Minnesota
Hook'D on Access
MS Access MVP 2001-2016

RE: Using Replace function as Criteria for Dlookup

(OP)
That worked. Thank you for you for your help!

Red Flag This Post

Please let us know here why this post is inappropriate. Reasons such as off-topic, duplicates, flames, illegal, vulgar, or students posting their homework.

Red Flag Submitted

Thank you for helping keep Tek-Tips Forums free from inappropriate posts.
The Tek-Tips staff will check this out and take appropriate action.

Reply To This Thread

Posting in the Tek-Tips forums is a member-only feature.

Click Here to join Tek-Tips and talk with other members!

Resources

Close Box

Join Tek-Tips® Today!

Join your peers on the Internet's largest technical computer professional community.
It's easy to join and it's free.

Here's Why Members Love Tek-Tips Forums:

Register now while it's still free!

Already a member? Close this window and log in.

Join Us             Close