Tek-Tips is the largest IT community on the Internet today!

Members share and learn making Tek-Tips Forums the best source of peer-reviewed technical information on the Internet!

  • Congratulations Chris Miller on being selected by the Tek-Tips community for having the most helpful posts in the forums last week. Way to Go!

Duplicate Records 1

Status
Not open for further replies.

bcooler

Programmer
Jun 13, 2009
132
I have a form that is being filled out. I need to prevent duplicate entries (a duplicate is defined as ALL field values from one record match ALL the field values on any other record).

Now, I've used Dcount quite a bit, but I'm having a little problem here. I can get no value for Dcount except zero.

Code:
    If DCount("[txtMultiplier_ID]", "tblMultiplier", "[Manufacturer] = """ & Nz(Me.cboManuf) & """ AND [PartType] = """ & Nz(Me.cboPartType) & """ AND [DiscountCode] = """ & _
        Nz(Me.cboDiscount) & """ AND [VolDiscount-Low] = " & Nz(Me.txtVolLow) & " AND [VolDiscount-High] = " & Nz(Me.txtVolHigh) & " AND [Multiplier_ID] <> " & _
            Nz(Me.txtMultiplier_ID)) > 0 Then
        Cancel = True
        If MsgBox("This would create duplicate conditions.  Press 'OK' to return and complete form.  Press 'Cancel' to undo changes.", vbOKCancel, "Please Complete Entry") = vbCancel Then
            Me.Undo
        End If
        Exit Sub

    End If

In some cases, some records under review will have blank fields. After some troubleshooting, it appears that blank fields (such as [DiscountCode]) are considered Null, which, I think, messes with the Dcount function. I have used Nz to make sure the form's text boxes are not null, but I don't think I can prevent it on the Field side of things.

Am I correct about Null, or is there something else going on? I only get 0 for an answer when I know there is at least 1 matching record.

Thanks!
 
What about this ?
Code:
If DCount("txtMultiplier_ID", "tblMultiplier", "Nz(Manufacturer)='" & Nz(Me!cboManuf) & _
    "' AND Nz(PartType)='" & Nz(Me!cboPartType) & _
    "' AND Nz(DiscountCode)='" & Nz(Me!cboDiscount) & _
    "' AND Nz([VolDiscount-Low])=" & Nz(Me!txtVolLow) & _
    " AND Nz([VolDiscount-High])=" & Nz(Me!txtVolHigh) & _
    " AND Nz(Multiplier_ID)<>" & Nz(Me!txtMultiplier_ID)) > 0 Then

Hope This Helps, PH.
FAQ219-2884
FAQ181-2886
 
Excellent! I previously attempted to do this, but I must have gotten the syntax wrong. Works perfectly!

The only thing I did differently was to use two "" in place of ', which prevent apostrophe's in my values from confusing the whole string. (at least, that's what Allen Browne says).

Thanks so much!
 
Spoke too early.....

The solution worked on a couple of examples, but later gave 'Syntax' errors. I'm confident it still had to do with missing info in text/combo boxes, so I got around it by building the filter as a variable (like Allen Browne does)...

Code:
    DupMult = "Nz(Manufacturer)= """ & Nz(Me!cboManuf) & """" 'setting up Dcount Filter based on non-empty fields
    If Nz(Me.cboPartType) <> Empty Then DupMult = DupMult & " AND Nz(PartType)=""" & Nz(Me!cboPartType) & """"
    If Nz(Me.cboDiscount) <> Empty Then DupMult = DupMult & " AND Nz(DiscountCode)=""" & Nz(Me!cboDiscount) & """"
    If Nz([VolDiscount-Low]) <> Empty Then DupMult = DupMult & " AND Nz([VolDiscount-Low])=" & Nz(Me!txtVolLow)
    If Nz([VolDiscount-High]) <> Empty Then DupMult = DupMult & " AND Nz([VolDiscount-High])=" & Nz(Me!txtVolHigh)
    
    DupMult = DupMult & " AND Nz(Multiplier_ID)<> " & Nz(Me!txtMultiplier_ID)

    If DCount("txtMultiplier_ID", "tblMultiplier", DupMult) > 0 Then
        Cancel = True
        If MsgBox("This would create duplicate conditions.  Press 'OK' to return and complete form.  Press 'Cancel' to undo changes.", vbOKCancel, "Please Complete Entry") = vbCancel Then
            Me.Undo
        End If
        Exit Sub
    End If
 
Status
Not open for further replies.

Part and Inventory Search

Sponsor

Back
Top