No duplicate records problem

R

Russ

I've got a fairly simple db with only 4 tables. Only two are linked
by a field called E58# with a one to many relationship. In the
"many" table I want to allow a field's (Item#) value for each record
to contain a number 1, 2, or 3 and not duplicate the number under the
same E58# when entering data with a form.

However, in table design when I give it an index of 'Yes, no
duplicates' I cannot enter another Item# 1 or 2 or 3 in a different
record with a different E58#. I only want to restrict duplicity when
the E58# is the same. How can I do this?

I've tried making multiple keyed fields using both fields but if in
error a person enters the duplicate field value it is quite difficult
to extract yourself from the error. Even deleting the record in error
retrurns a message about no null values in key fields.
 
F

Fred

BTW, I personally wouldn't use a # sign in a field name, but if it works.......

Try: Set it up as a multi-field (on E58# and Item# fields) index, not a
multi-field key. Set unique to Y. You could also set it to ignore nulls.
 
F

Fred

In 2003 it's obscure but there.....hopefully the same in 2K. ?

On the index grid, on the next line down from the first field index, enter a
new line, leave the index spot blank and enter the 2nd field name.
 
J

John W. Vinson

I've got a fairly simple db with only 4 tables. Only two are linked
by a field called E58# with a one to many relationship. In the
"many" table I want to allow a field's (Item#) value for each record
to contain a number 1, 2, or 3 and not duplicate the number under the
same E58# when entering data with a form.

However, in table design when I give it an index of 'Yes, no
duplicates' I cannot enter another Item# 1 or 2 or 3 in a different
record with a different E58#. I only want to restrict duplicity when
the E58# is the same. How can I do this?

I've tried making multiple keyed fields using both fields but if in
error a person enters the duplicate field value it is quite difficult
to extract yourself from the error. Even deleting the record in error
retrurns a message about no null values in key fields.

The unique index won't work for the exact reason you describe: that field
ISN'T unique.

What you can do is create a two field unique index on the E58# field and the
Item# field (do note that # is a date delimiter and may best be avoided in
fieldnames). In addition you can have Access automatically assign the Item#
and have your form check for duplicates, avoiding the table error. In the
form's BeforeInsert event you can put code

Private Sub Form_BeforeInsert(Cancel as Integer)
Me![Item#] = NZ(DMax("[Item#]", "
", "[E58#] = " & Me![E58#])) + 1
End Sub

and then check for duplicates before saving, just in case the user types a
value into the field:

Private Sub Form_BeforeUpdate(Cancel as Integer)
If Not IsNull(DLookUp("[Item#]", "table", _
"[E58#] = " & Me.[E58#] & " AND [Item#] = " & Me![Item#])) Then
MsgBox "Duplicate item number!", vbOKOnly
Cancel = True
End If
End Sub
 
R

Russ

Well, I was able to create the multi field index, but it would only
warn me of the duplicate values after I tried to move off that record.
Then, I could not delete that record with a delete record command but
had to close the form itself. I've got the index set to ignore nulls
as well.
 
R

Russ

John,

I was able to delete the record after entering your code, but the form
will not insert a digit into the ItemNo field (I've renamed and
removed the # symbol and replaced them with "No") when I insert a new
record.

I've got a fairly simple db with only 4 tables. Only two are linked
by a field called E58# with a one to many relationship. In the
"many" table I want to allow a field's (Item#) value for each record
to contain a number 1, 2, or 3 and not duplicate the number under the
same E58# when entering data with a form.

However, in table design when I give it an index of 'Yes, no
duplicates' I cannot enter another Item# 1 or 2 or 3 in a different
record with a different E58#. I only want to restrict duplicity when
the E58# is the same. How can I do this?

I've tried making multiple keyed fields using both fields but if in
error a person enters the duplicate field value it is quite difficult
to extract yourself from the error. Even deleting the record in error
retrurns a message about no null values in key fields.

The unique index won't work for the exact reason you describe: that field
ISN'T unique.

What you can do is create a two field unique index on the E58# field and the
Item# field (do note that # is a date delimiter and may best be avoided in
fieldnames). In addition you can have Access automatically assign the Item#
and have your form check for duplicates, avoiding the table error. In the
form's BeforeInsert event you can put code

Private Sub Form_BeforeInsert(Cancel as Integer)
Me![Item#] = NZ(DMax("[Item#]", "
", "[E58#] = " & Me![E58#])) + 1
End Sub

and then check for duplicates before saving, just in case the user types a
value into the field:

Private Sub Form_BeforeUpdate(Cancel as Integer)
If Not IsNull(DLookUp("[Item#]", "table", _
"[E58#] = " & Me.[E58#] & " AND [Item#] = " & Me![Item#])) Then
MsgBox "Duplicate item number!", vbOKOnly
Cancel = True
End If
End Sub
 
R

Russ

What you can do is create a two field unique index on the E58# field and the
Item# field (do note that # is a date delimiter and may best be avoided in
fieldnames). In addition you can have Access automatically assign the Item#
and have your form check for duplicates, avoiding the table error. In the
form's BeforeInsert event you can put code

Private Sub Form_BeforeInsert(Cancel as Integer)
Me![Item#] = NZ(DMax("[Item#]", "
", "[E58#] = " & Me![E58#])) + 1
End Sub

and then check for duplicates before saving, just in case the user types a
value into the field:

Private Sub Form_BeforeUpdate(Cancel as Integer)
If Not IsNull(DLookUp("[Item#]", "table", _
"[E58#] = " & Me.[E58#] & " AND [Item#] = " & Me![Item#])) Then
MsgBox "Duplicate item number!", vbOKOnly
Cancel = True
End If
End Sub



John,

After screwing up and putting your code in the wrong form, I finally
got it located in the subform where it belongs. However it will not
insert a new Item number in the ItemNo field when I add a record. I
also get an error message when I try to exit the form which says:
Run time error 2465.
Microsoft Access can't fiind the field 'I' referred to inyour
expression. (the 'I' looks like a pipe symbol that I couldn't find on
my keyboard)

Here's what I entered:
Private Sub Form_BeforeInsert(Cancel As Integer)
Me![ItemNo] = Nz(DMax("[ItemNo]", "[Items]", "[E58No] = " &
Me![E58No])) + 1
End Sub

Private Sub Form_BeforeUpdate(Cancel As Integer)
If Not IsNull(DLookup("[ItemNo]", "Items", _
"[E58No] = " & Me.[E58No] & " AND [ItemNo] = " & Me![ItemNo])) Then
MsgBox "Duplicate item number!", vbOKOnly
Cancel = True
End If
End Sub
 
J

John W. Vinson

John,

I was able to delete the record after entering your code, but the form
will not insert a digit into the ItemNo field (I've renamed and
removed the # symbol and replaced them with "No") when I insert a new
record.

Please post your code, and indicate the datatypes of your fields. If either of
them are Text fields instead of Number you need to tweak the code a bit.
 
J

John W. Vinson

After screwing up and putting your code in the wrong form, I finally
got it located in the subform where it belongs. However it will not
insert a new Item number in the ItemNo field when I add a record. I
also get an error message when I try to exit the form which says:
Run time error 2465.
Microsoft Access can't fiind the field 'I' referred to inyour
expression. (the 'I' looks like a pipe symbol that I couldn't find on
my keyboard)

Here's what I entered:
Private Sub Form_BeforeInsert(Cancel As Integer)
Me![ItemNo] = Nz(DMax("[ItemNo]", "[Items]", "[E58No] = " &
Me![E58No])) + 1
End Sub

Private Sub Form_BeforeUpdate(Cancel As Integer)
If Not IsNull(DLookup("[ItemNo]", "Items", _
"[E58No] = " & Me.[E58No] & " AND [ItemNo] = " & Me![ItemNo])) Then
MsgBox "Duplicate item number!", vbOKOnly
Cancel = True
End If
End Sub

The code assumes that your Subform has controls named [E85No] and [ItemNo]. If
it doesn't, add controls of those names bound to the corresponding fields, or
(perhaps better) textboxes named txtE85No and txtItemNo and replace the
Me![E85No] and Me![ItemNo] references with Me![txtE85No] and Me![txtItemno].
The textboxes can be invisible if you wish.
 
R

Russ

Please post your code, and indicate the datatypes of your fields. If either of
them are Text fields instead of Number you need to tweak the code a bit.


My two fields in question are both text fields. I can probably change
them to Number if you think it will work better.
 
R

Russ

After screwing up and putting your code in the wrong form, I finally
got it located in the subform where it belongs. However it will not
insert a new Item number in the ItemNo field when I add a record. I
also get an error message when I try to exit the form which says:
Run time error 2465.
Microsoft Access can't fiind the field 'I' referred to inyour
expression. (the 'I' looks like a pipe symbol that I couldn't find on
my keyboard)

Here's what I entered:
Private Sub Form_BeforeInsert(Cancel As Integer)
Me![ItemNo] = Nz(DMax("[ItemNo]", "[Items]", "[E58No] = " &
Me![E58No])) + 1
End Sub

Private Sub Form_BeforeUpdate(Cancel As Integer)
If Not IsNull(DLookup("[ItemNo]", "Items", _
"[E58No] = " & Me.[E58No] & " AND [ItemNo] = " & Me![ItemNo])) Then
MsgBox "Duplicate item number!", vbOKOnly
Cancel = True
End If
End Sub

The code assumes that your Subform has controls named [E85No] and [ItemNo]. If
it doesn't, add controls of those names bound to the corresponding fields, or
(perhaps better) textboxes named txtE85No and txtItemNo and replace the
Me![E85No] and Me![ItemNo] references with Me![txtE85No] and Me![txtItemno].
The textboxes can be invisible if you wish.


Although I did initailly change the field names to E58No and ItemNo, I
neglected to change the control names in the form. I did change them
after your advice, but I'm still getting the above problem.
 
R

Russ

After screwing up and putting your code in the wrong form, I finally
got it located in the subform where it belongs. However it will not
insert a new Item number in the ItemNo field when I add a record. I
also get an error message when I try to exit the form which says:
Run time error 2465.
Microsoft Access can't fiind the field 'I' referred to inyour
expression. (the 'I' looks like a pipe symbol that I couldn't find on
my keyboard)

Here's what I entered:
Private Sub Form_BeforeInsert(Cancel As Integer)
Me![ItemNo] = Nz(DMax("[ItemNo]", "[Items]", "[E58No] = " &
Me![E58No])) + 1
End Sub

Private Sub Form_BeforeUpdate(Cancel As Integer)
If Not IsNull(DLookup("[ItemNo]", "Items", _
"[E58No] = " & Me.[E58No] & " AND [ItemNo] = " & Me![ItemNo])) Then
MsgBox "Duplicate item number!", vbOKOnly
Cancel = True
End If
End Sub

The code assumes that your Subform has controls named [E85No] and [ItemNo]. If
it doesn't, add controls of those names bound to the corresponding fields, or
(perhaps better) textboxes named txtE85No and txtItemNo and replace the
Me![E85No] and Me![ItemNo] references with Me![txtE85No] and Me![txtItemno].
The textboxes can be invisible if you wish.

I changed the field types to Number Long integer. In the ItemNo field
of the form, I've got <4 in the validation rule property. When I
enter 4 in that field I get the required validation text I wanted, but
after deleting the digit or trying to delete the entire record I
cannot get out of the field or close the form without the same message
popping up.
 
J

John W. Vinson

My two fields in question are both text fields. I can probably change
them to Number if you think it will work better.

Text should be ok, but since you're doing arithmatic on it, Number... Long
Integer would be better for ItemNo. If E58No is a Text field you just need
some syntactially required quotemarks, either ' or " - the singlequote is
easier. Try changing the datatype of ItemNo and use

Private Sub Form_BeforeInsert(Cancel As Integer)
Me![ItemNo] = Nz(DMax("[ItemNo]", "[Items]", "[E58No] = '" &
Me![E58No]) & "'") + 1
End Sub

Private Sub Form_BeforeUpdate(Cancel As Integer)
If Not IsNull(DLookup("[ItemNo]", "Items", _
"[E58No] = '" & Me.[E58No] & "' AND [ItemNo] = " & Me![ItemNo])) Then
MsgBox "Duplicate item number!", vbOKOnly
Cancel = True
End If
End Sub
 
J

John W. Vinson

The code assumes that your Subform has controls named [E85No] and [ItemNo]. If
it doesn't, add controls of those names bound to the corresponding fields, or
(perhaps better) textboxes named txtE85No and txtItemNo and replace the
Me![E85No] and Me![ItemNo] references with Me![txtE85No] and Me![txtItemno].
The textboxes can be invisible if you wish.

I changed the field types to Number Long integer. In the ItemNo field
of the form, I've got <4 in the validation rule property. When I
enter 4 in that field I get the required validation text I wanted, but
after deleting the digit or trying to delete the entire record I
cannot get out of the field or close the form without the same message
popping up.

oops... we're crossing messages in the two different subthreads here! I just
posted how to do it with text fields. You're better off with numbers, just
leave out the ' marks in my other answer.

The BeforeInsert code should make it *unnecessary* to manually enter an ItemNo
value, since it will calculate one for you automatically. Can you just hit
<Esc><Esc> to cancel editing the record? Why the validation rule anyway - you
want to limit it to three items? Note that a validation rule of < 4 permits
-12320185123 as a valid itemno... <g>
 
R

Russ

The code assumes that your Subform has controls named [E85No] and [ItemNo]. If
it doesn't, add controls of those names bound to the corresponding fields, or
(perhaps better) textboxes named txtE85No and txtItemNo and replace the
Me![E85No] and Me![ItemNo] references with Me![txtE85No] and Me![txtItemno].
The textboxes can be invisible if you wish.

I changed the field types to Number Long integer. In the ItemNo field
of the form, I've got <4 in the validation rule property. When I
enter 4 in that field I get the required validation text I wanted, but
after deleting the digit or trying to delete the entire record I
cannot get out of the field or close the form without the same message
popping up.

oops... we're crossing messages in the two different subthreads here! I just
posted how to do it with text fields. You're better off with numbers, just
leave out the ' marks in my other answer.

The BeforeInsert code should make it *unnecessary* to manually enter an ItemNo
value, since it will calculate one for you automatically. Can you just hit
<Esc><Esc> to cancel editing the record? Why the validation rule anyway - you
want to limit it to three items? Note that a validation rule of < 4 permits
-12320185123 as a valid itemno... <g>


You are right about not having to enter a number in the ItemNo field.
I had been manually entering it myself, but when I started writing the
description of the ItemNo one was entered for me. Very good.

I've put the validation rule in there to liimit the entry to no more
than 3 items per E58No. However, it does not appear to be doing it's
job since the code was able to enter a 4th ItemNo. I will change it
to 1 Or 2 Or 3 to eliiminate the minus numbers, but I don't think that
will solve the *4th ItemNo* problem.
 
J

John W. Vinson

You are right about not having to enter a number in the ItemNo field.
I had been manually entering it myself, but when I started writing the
description of the ItemNo one was entered for me. Very good.

I've put the validation rule in there to liimit the entry to no more
than 3 items per E58No. However, it does not appear to be doing it's
job since the code was able to enter a 4th ItemNo. I will change it
to 1 Or 2 Or 3 to eliiminate the minus numbers, but I don't think that
will solve the *4th ItemNo* problem.

Trap the fourth itemno in the BeforeInsert event instead:

Private Sub Form_BeforeInsert(Cancel As Integer)
If DCount("*", "[Items]", " [E58No] = " & Me![E58No]) >= 3 Then
MsgBox "Only three items per E58 please", vbOKOnly
Cancel = True
Else
Me![ItemNo] = Nz(DMax("[ItemNo]","[Items]","[E58No] = " & Me![E58No])) + 1
End If
End Sub

The problem with the validation rule is that it fires too late - after you've
entered all the data for the record and then try to save it.
 
R

Russ

You are right about not having to enter a number in the ItemNo field.
I had been manually entering it myself, but when I started writing the
description of the ItemNo one was entered for me. Very good.

I've put the validation rule in there to liimit the entry to no more
than 3 items per E58No. However, it does not appear to be doing it's
job since the code was able to enter a 4th ItemNo. I will change it
to 1 Or 2 Or 3 to eliiminate the minus numbers, but I don't think that
will solve the *4th ItemNo* problem.

Trap the fourth itemno in the BeforeInsert event instead:

Private Sub Form_BeforeInsert(Cancel As Integer)
If DCount("*", "[Items]", " [E58No] = " & Me![E58No]) >= 3 Then
MsgBox "Only three items per E58 please", vbOKOnly
Cancel = True
Else
Me![ItemNo] = Nz(DMax("[ItemNo]","[Items]","[E58No] = " & Me![E58No])) + 1
End If
End Sub

The problem with the validation rule is that it fires too late - after you've
entered all the data for the record and then try to save it.

Very nice John! Thank you very much for the help and the extra added
info.

Russ
 

Ask a Question

Want to reply to this thread or ask your own question?

You'll need to choose a username for the site, which only take a couple of moments. After that, you can post your question and our members will help you out.

Ask a Question

Top