It's the Events form's event procedures you use here, not the subform
control's. The combo box on the EventStaffing Subform, I'll call it
cboContact for this example, needs to be requeried when the Events form's
ServiceID changes so that its list will reflect the changed ServiceID.
The
ServiceID could change when you move to a different record in the parent
form
or when you add a new event, so the two event procedures of the Events
form
in which you need to requery the combo box are its Current and AfterInsert
event procedures, though it might be better to use the AfterUpdate rather
than AfterInsert event procedure as its theoretically possible that the
ServiceID for an existing event record could be changed (I'd assumed it
would
be static, but that's perhaps a rash assumption). The AfterUpdate event
fires for both new and changed records so would cover both possibilities.
The combo box is referenced via the subform control's Form property, so
the
syntax would be:
Me.[EventStaffing Subform].Form.[cboContact].Requery
Ken Sheridan
Stafford, England
Ronald Marchand said:
Ken:
You wrote:
(they do have real names but you have to move in the right social
circles
to use them!).
Fortunately, here in the colonies we don't have that problem, although
some
local politicians think they are royalty.
I am confused on one point.
You'll need to requery the contact combo box on the subform both in the
parent form's Current event procedure and in its AfterInsert event
procedure
Rephrased:
"ComboBox on the subform in the ParentForm"
The parent form is Events and the subform is "EventStaffing Subform" and
its
control is named the same thing. There are only two events here are "On
Enter" and "On Exit". I know I am not understanding what you wrote and I
am
not sure where to put it.
Thanks
Ron Marchand
Ron:
The control needs to be requeried whenever the EventID of the main
parent
form changes, i.e. when you move the parent form to another record, or
enter
a new event record. This is because the parameter in the combo box's
RowSource which references the EventID does not reflect the new value
until
it is requeried.
You can easily eliminate any duplicates by changing the RowSource to:
SELECT DISTINCT Contacts.ContactID, (FirstName + " ") & LastName
FROM Contacts INNER JOIN ContactServices
ON ContactServices.ContactID = Contacts.ContactID
WHERE Active = TRUE
AND ContactServices.ServiceID = Parent!ServiceID
ORDER BY LastName, FirstName;
The DISTINCT option restricts the result set to just one instance of
each
row where two or more rows return the same data.
Incidentally you might have wondered why the expression (FirstName + "
")
&
LastName is used to build the full name rather than simply FirstName &
" "
&
LastName. It allows for a missing first name. If you have any British
upper
crust individuals amongst your contacts for instance, e.g. our local
aristo
Lord Stafford, he would be just called Stafford (they do have real
names
but
you have to move in the right social circles to use them!). When a
space
is
tacked onto a Null first name using the + operator the space is
suppressed
because Nulls 'propagate', i.e. Null + anything = Null. If the &
concatenation character is used, however, then the space is not
suppressed
so
you'd end up with an unwanted space at the start of the name. Making
use
of
the propagation of Nulls is a useful little trick here (more so if you
have
names with or without middle names or initials), but when dealing with
data
such as financial amounts its important as if you try and add values in
currency fields for instance and one is Null the result will be Null.
Currency fields in a table should normally be given a default value of
zero
and 'required' so you never have a Null. This also reduces any
ambiguity,
e.g. a zero credit rating means exactly that, but a Null credit rating
has
no
intrinsic meaning, so it could mean no credit, unlimited credit or
anything
else you can think of, because a Null is an 'unknown' not an equivalent
of
zero.
Ken Sheridan
Stafford, England
:
Ken:
Thank you a hundred times.
This worked. I am a novice with Access and I spent hours toiling over
this
one. Access will not graphically display this query and I was trying
to
develop it graphically.
I do have two questions.
1. Why the need for the requery?
2. Can the list be limited to not present a name if it is already in
the
EventStaff table.
I don't want to wind up with
1 John Doe
1 Jane Doe
1 John Doe ---- duplicate
Ron Marchand
Kenner, LA. (USA)
message
Ron:
I don't see any reason why you need the query joining the three
tables
as
the subform's RecordSource. Simply the EventStaffing table will do,
unless
you want to sort the subform's rows by staff name, in which case use
a
query
joining it to Contacts and ORDER BY LastName, Firstname. The
subform
will
be
linked to the parent form on EventID.
The RowSource for the combo box on the subform bound to ContactID
needs
to
return the ContactID and the concatenated first and last names from
the
Contacts table where the contact's Active value is True, and where
the
ServiceID value in the row in ContactServices for the contact
matches
the
current ServiceID value. For this you need to join the Contacts
table
to
the
ContactServices table and restrict the result set by means of a
parameter
referencing the form's ServiceID. As you are dealing with a
property
of a
control on the subform you can use the Parent property to reference
the
main
form rather than a fully qualified reference. So the RowSource
would
be
like
this:
SELECT Contacts.ContactID, (FirstName + " ") & LastName
FROM Contacts INNER JOIN ContactServices
ON ContactServices.ContactID = Contacts.ContactID
WHERE Active = TRUE
AND ContactServices.ServiceID = Parent!ServiceID
ORDER BY LastName, FirstName;
Set the control's BoundColumn property to 1, its ColumnCount
property
to 2
and its ColumnWidths to 0cm;8cm (or rough equivalent in inches, but
the
first
dimension must be zero to hide the first column).
You'll need to requery the contact combo box on the subform both in
the
parent form's Current event procedure and in its AfterInsert event
procedure.
The control on the subform is referenced via the Form property of
the
subform control (that's the control in the main form which houses
the
subform), e.g.
Me.YourSubformControl.Form.cboContact.Requery
Ken Sheridan
Stafford, England
:
I hope that someone can assist me with a little dilemma
I have a database which as the following tables/fields
Contacts
ContactID
LastName
FirstName
Active (yes/no)
(other info fields)
ContactServices
ContactID
ServiceID
Services
ServiceID
ServiceDescription
Events
EventID
EventDescription
ServiceID
(other info fields)
EventStaff
EventID
ContactID
I have a form/subform to fill in Events/EventStaff. The EventStaff
subform
has a combo box to look up the contacts to assign. This lookup must
present
the ContactID, LastName, FirstName of any contact who is
A. Active = True
If the Active status goes false, they remain in the table and
displayed on the form.
B. Whose ContactServices.ServiceID = Events.ServiceID