
Probably you are not searching as expected. So, insert a line with Debug to list the actual search:
Debug.Print "Criteria:", strCriteria
rs.FindFirst strCriteria
This browser is no longer supported.
Upgrade to Microsoft Edge to take advantage of the latest features, security updates, and technical support.
I am trying to bring up a form record based on text entered in a text box.
The form "Furnace + Header Data Form" is a parent form, with 2 subforms called "Header Data Form" and "Surrogate Data Form". This question is in relation to the "Header Data Form" subform.
The parent form is used to enter data on different furnace runs, which is connected to the table "Furnace Run Data". Each furnace run will have several headers in it, and each header has a serial number. I added a subform called "Header Data Form", which will allow the user to enter information specific to each header serial number. Data that is entered into the "Header Data Form" subform adds data to the "Header Data" table and is connected to the furnace data table via the Furnace Run ID. The Furnace Run ID is on both the parent form and as an invisible field on the Header Data subform. All fields on the Header Data Form are connected to the Header Data Table.
As a side note, there is a button within this subform to add a new record. Once the button is clicked, a new record with the furnace data and header data is saved and the header data subform is cleared. When you enter more data into the header data form and click the add button, another line (with the same Furnace Run ID) will be added to the header data table. No data is added to the furnace table. This all works great. There are multiple records in the Header Data table for each Furnace Run ID.
Initially, I was trying to find the record based on a text field named "Header SN Field" on the subform named "Header Data Form". This text field is connected to the "Header SN" Field from the "Header Data" table. Upon clicking the search button (on the Header Data subform), I wanted to use the text typed into the Header SN Field to search for the previous record in the Header Data table that has Header SN (field in Header Data table) = Header SN Field (field in form where user enters text). I could get this to run with no errors, but I kept getting the message saying that no matching record was found, even though there definitely is an existing record with the matching Header SN. My code for this is below.
Private Sub Search_SN_Button_Click()
If ([Header SN Placeholder] & vbNullString) = vbNullString Then Exit Sub
Dim strCriteria As String
Dim rs As DAO.Recordset
Set rs = Me.RecordsetClone
strCriteria = "[Header SN]='" & Me.[Header SN Field] & "'"
rs.FindFirst strCriteria
If rs.NoMatch Then
MsgBox "Sorry, no such record '" & [Header SN Field] & "' was found.", _
vbOKOnly + vbInformation
Else
Me.Bookmark = rs.Bookmark
End If
rs.Close
txtGoTo = Null
End Sub
After searching a bit, I thought the solution might be to have a text box and search button on the main form instead. The text box on the main form is called "HeaderSN". I am still getting the message that there is no existing record that matches. My code for this is below.
Private Sub Search_Header_SN_Record_Click()
If (HeaderSN & vbNullString) = vbNullString Then Exit Sub
Dim strCriteria As String
Dim rs As DAO.Recordset
Set rs = Me.[Header Data Form].Form.RecordsetClone
strCriteria = "Header SN = '" & Me.HeaderSN & "'"
rs.FindFirst strCriteria
If rs.NoMatch Then
MsgBox "Sorry, no such record '" & [HeaderSN] & "' was found.", _
vbOKOnly + vbInformation
Else
Me.[Header Data Form].Form.Bookmark = rs.Bookmark
End If
rs.Close
txtGoTo = Null
End Sub
Can someone please help me with this? I have tried a million different ways to do this and have been searching for days on different forums but I can't figure it out.
Probably you are not searching as expected. So, insert a line with Debug to list the actual search:
Debug.Print "Criteria:", strCriteria
rs.FindFirst strCriteria
You might like to take a look at FindRecord.zip in my public databases folder at:
https://onedrive.live.com/?cid=44CC60D7FEA42912&id=44CC60D7FEA42912!169
If you have trouble downloading a specific file, clicking on the 'Download' button at the top of the page while no files are selected should download a zip file of all files in the folder, from which you should then be able to unpack the relevant file.
This little demo includes two methods for searching on the basis of a value in a row in a subform. The first filters the parent form only, using the following code:
Private Sub cboLastname_AfterUpdate()
Const MESSAGETEXT = "No matching records found."
Dim ctrl As Control
Dim strFilter As String
Set ctrl = Me.ActiveControl
strFilter = "ProjectID IN(SELECT ProjectID " & _
"FROM ContactProjects WHERE ContactID = " & ctrl & ")"
If Nz(ctrl, 0) = 0 Then
' turn off filter
Me.FilterOn = False
Else
If Not IsNull(DLookup("ContactID", "ContactProjects", "ContactID = " & ctrl)) Then
' filter form to name selected in combo box
Me.Filter = strFilter
Me.FilterOn = True
Else
' inform user if no matching records found and show all records
MsgBox MESSAGETEXT, vbInformation, "Warning"
Me.FilterOn = False
Me.Requery
End If
End If
End Sub
The second filters both the form and subform, using the following code:
Private Sub cboLastname_AfterUpdate()
Const MESSAGETEXT = "No matching records found."
Dim ctrl As Control
Dim strFilter As String
Set ctrl = Me.ActiveControl
strFilter = "ProjectID IN(SELECT ProjectID " & _
"FROM ContactProjects WHERE ContactID = " & ctrl & ")"
If Nz(ctrl, 0) = 0 Then
' turn off filter
Me.FilterOn = False
Me.fsubContacts.Form.FilterOn = False
Else
If Not IsNull(DLookup("ContactID", "ContactProjects", "ContactID = " & ctrl)) Then
' filter form to name selected in combo box
Me.Filter = strFilter
Me.FilterOn = True
' filter subform to selected contact
Me.fsubContacts.Form.Filter = "ContactID = " & ctrl
Me.fsubContacts.Form.FilterOn = True
Else
' inform user if no matching records found and show all records
MsgBox MESSAGETEXT, vbInformation, "Warning"
Me.FilterOn = False
Me.Requery
Me.fsubContacts.Form.FilterOn = False
End If
End If
End Sub
Start making sure, you are actually searching using the right criteria. As noted above:
Debug.Print "Criteria:", strCriteria
rs.FindFirst strCriteria
From your original post my understanding is that you wish to enter a value into an unbound text box in a parent form, and move the parent form to a record where the value you entered is present in a subform, i.e. where it is present in a row in a related table where the row references the record shown in the parent form.
The code I gave you does this by building a string expression which filters the parent form's recordset to the row or rows where the value of the primary key is found as a foreign key in the row or rows in the table to which the subform is bound where the value in another column is that which you entered in the unbound text box.
If you have downloaded my demo you will see that the subform's Current event procedure includes the following code which, when the parent form is filtered by means of the unbound combo box, moves the subform to the record whose value was entered in the unbound combo box:
Private Sub Form_Current()
' select contact in subform if combo box is not Null
If Not IsNull(Me.cboLastname) Then
With Me.fsubContacts.Form
.RecordsetClone.FindFirst "ContactID = " & Me.cboLastname
If Not .RecordsetClone.NoMatch Then
.Bookmark = .RecordsetClone.Bookmark
End If
End With
End If
End Sub
I did not give this code in my original reply because, the subform being in continuous forms view, it is not essential to the process, but where the subform is in single form view, it would be necessary to include code like this to show the record in question. Alternatively the subform itself can be filtered, as in the second example I gave you.
If my understanding of what you are attempting is correct, you will need to amend the references in the code so that it refers to your own table, columns and control names, including the subform control, i.e. that in the parent form which houses the subform. You might also need to wrap values in literal quotes characters if the primary and foreign keys are of text data type rather than numeric as in my demo.
As far as I can see, what you are attempting is essentially the same as in my demo, so you need to use the same methodology. This means filtering the parent form so that it shows the parent record which is referenced by the record in the subform to which you want to navigate, and then navigating to the appropriate record in the subform. Either of the solutions used by my demo will do this, so you need to adapt my code so that it references the objects in your own database. I don't think I can add anything to what I've said previously.