Copying filter results on a search form into a table or query (1 Viewer)

mounty76

Registered User.
Local time
Today, 13:57
Joined
Sep 14, 2017
Messages
341
Hello All,

I have a form that uses search criteria to filter out the records.

Once they are filtered is there anyway can I put the filtered results into a query or table so that I can use them elsewhere in a report etc.

Thanks again
 

Gasman

Enthusiastic Amateur
Local time
Today, 21:57
Joined
Sep 21, 2011
Messages
14,298
Use your strWhere string as the query/report criteria?
 

theDBguy

I’m here to help
Staff member
Local time
Today, 13:57
Joined
Oct 29, 2018
Messages
21,473
Hi. I agree. How do you construct the "search criteria" for the form?
 

mounty76

Registered User.
Local time
Today, 13:57
Joined
Sep 14, 2017
Messages
341
Code:
Private Sub cmdFilter_Click()
    'Purpose:   Build up the criteria string form the non-blank search boxes, and apply to the form's Filter.
    'Notes:     1. We tack " AND " on the end of each condition so you can easily add more search boxes; _
                        we remove the trailing " AND " at the end.
    '           2. The date range works like this: _
                        Both dates      = only dates between (both inclusive. _
                        Start date only = all dates from this one onwards; _
                        End date only   = all dates up to (and including this one).
    Dim strWhere As String                  'The criteria string.
    Dim lngLen As Long                      'Length of the criteria string to append to.
    Const conJetDate = "\#mm\/dd\/yyyy\#"   'The format expected for dates in a JET query string.
   
    '***********************************************************************
    'Look at each search box, and build up the criteria string from the non-blank ones.
    '***********************************************************************
    'Text field example. Use quotes around the value in the string.
    If Not IsNull(Me.txtFilterDesc) Then
        strWhere = strWhere & "([Description] Like ""*" & Me.txtFilterDesc & "*"") AND "
    End If
   
    'Another text field example. Use Like to find anywhere in the field.
    If Not IsNull(Me.txtFilterSupplier) Then
        strWhere = strWhere & "([Supplier] Like ""*" & Me.txtFilterSupplier & "*"") AND "
    End If
   
    'Number field example. Do not add the extra quotes.
    If Not IsNull(Me.cboFilterCode) Then
        strWhere = strWhere & "([Code] = """ & Me.cboFilterCode & """) AND "
    End If
   
       If Not IsNull(Me.Check56) Then
        strWhere = strWhere & "([Invoice]  ) AND "
    End If
   
           If Not IsNull(Me.Check58) Then
        strWhere = strWhere & "([Cash]  ) AND "
    End If
   
           If Not IsNull(Me.Check59) Then
        strWhere = strWhere & "([Soldo]  ) AND "
    End If
   
           If Not IsNull(Me.Check60) Then
        strWhere = strWhere & "([Centtrip]  ) AND "
    End If
   
    'Yes/No field and combo example. If combo is blank or contains "ALL", we do nothing.
    'If Me.cboFilterIsCorporate = -1 Then
       ' strWhere = strWhere & "([IsCorporate] = True) AND "
    'ElseIf Me.cboFilterIsCorporate = 0 Then
       ' strWhere = strWhere & "([IsCorporate] = False) AND "
   ' End If
   
    'Date field example. Use the format string to add the # delimiters and get the right international format.
    If Not IsNull(Me.txtStartDate) Then
        strWhere = strWhere & "([Date] >= " & Format(Me.txtStartDate, conJetDate) & ") AND "
    End If
   
    'Another date field example. Use "less than the next day" since this field has times as well as dates.
    If Not IsNull(Me.txtEndDate) Then   'Less than the next day.
        strWhere = strWhere & "([Date] < " & Format(Me.txtEndDate + 1, conJetDate) & ") AND "
    End If
   
    '***********************************************************************
    'Chop off the trailing " AND ", and use the string as the form's Filter.
    '***********************************************************************
    'See if the string has more than 5 characters (a trailng " AND ") to remove.
    lngLen = Len(strWhere) - 5
    If lngLen <= 0 Then     'Nah: there was nothing in the string.
        MsgBox "No criteria", vbInformation, "Nothing to do."
    Else                    'Yep: there is something there, so remove the " AND " at the end.
        strWhere = Left$(strWhere, lngLen)
        'For debugging, remove the leading quote on the next line. Prints to Immediate Window (Ctrl+G).
        Debug.Print strWhere
       
        'Finally, apply the string as the form's Filter.
       
        Me.Filter = strWhere
        Me.FilterOn = True
    End If
End Sub

Private Sub cmdReset_Click()
    'Purpose:   Clear all the search boxes in the Form Header, and show all records again.
    Dim ctl As Control
   
    'Clear all the controls in the Form Header section.
    For Each ctl In Me.Section(acHeader).Controls
        Select Case ctl.ControlType
        Case acTextBox, acComboBox, acCheckBox
            ctl.Value = Null
        'Case acCheckBox
            'ctl.Value = False
        End Select
    Next
   
    'Remove the form's filter.
    Me.FilterOn = False
End Sub

Mod Edit: Used proper code tags for ease of reading.
 
Last edited by a moderator:

theDBguy

I’m here to help
Staff member
Local time
Today, 13:57
Joined
Oct 29, 2018
Messages
21,473
Code:
Private Sub cmdFilter_Click()
    'Purpose:   Build up the criteria string form the non-blank search boxes, and apply to the form's Filter.
    'Notes:     1. We tack " AND " on the end of each condition so you can easily add more search boxes; _
                        we remove the trailing " AND " at the end.
    '           2. The date range works like this: _
                        Both dates      = only dates between (both inclusive. _
                        Start date only = all dates from this one onwards; _
                        End date only   = all dates up to (and including this one).
    Dim strWhere As String                  'The criteria string.
    Dim lngLen As Long                      'Length of the criteria string to append to.
    Const conJetDate = "\#mm\/dd\/yyyy\#"   'The format expected for dates in a JET query string.
 
    '***********************************************************************
    'Look at each search box, and build up the criteria string from the non-blank ones.
    '***********************************************************************
    'Text field example. Use quotes around the value in the string.
    If Not IsNull(Me.txtFilterDesc) Then
        strWhere = strWhere & "([Description] Like ""*" & Me.txtFilterDesc & "*"") AND "
    End If
 
    'Another text field example. Use Like to find anywhere in the field.
    If Not IsNull(Me.txtFilterSupplier) Then
        strWhere = strWhere & "([Supplier] Like ""*" & Me.txtFilterSupplier & "*"") AND "
    End If
 
    'Number field example. Do not add the extra quotes.
    If Not IsNull(Me.cboFilterCode) Then
        strWhere = strWhere & "([Code] = """ & Me.cboFilterCode & """) AND "
    End If
 
       If Not IsNull(Me.Check56) Then
        strWhere = strWhere & "([Invoice]  ) AND "
    End If
 
           If Not IsNull(Me.Check58) Then
        strWhere = strWhere & "([Cash]  ) AND "
    End If
 
           If Not IsNull(Me.Check59) Then
        strWhere = strWhere & "([Soldo]  ) AND "
    End If
 
           If Not IsNull(Me.Check60) Then
        strWhere = strWhere & "([Centtrip]  ) AND "
    End If
 
    'Yes/No field and combo example. If combo is blank or contains "ALL", we do nothing.
    'If Me.cboFilterIsCorporate = -1 Then
       ' strWhere = strWhere & "([IsCorporate] = True) AND "
    'ElseIf Me.cboFilterIsCorporate = 0 Then
       ' strWhere = strWhere & "([IsCorporate] = False) AND "
   ' End If
 
    'Date field example. Use the format string to add the # delimiters and get the right international format.
    If Not IsNull(Me.txtStartDate) Then
        strWhere = strWhere & "([Date] >= " & Format(Me.txtStartDate, conJetDate) & ") AND "
    End If
 
    'Another date field example. Use "less than the next day" since this field has times as well as dates.
    If Not IsNull(Me.txtEndDate) Then   'Less than the next day.
        strWhere = strWhere & "([Date] < " & Format(Me.txtEndDate + 1, conJetDate) & ") AND "
    End If
 
    '***********************************************************************
    'Chop off the trailing " AND ", and use the string as the form's Filter.
    '***********************************************************************
    'See if the string has more than 5 characters (a trailng " AND ") to remove.
    lngLen = Len(strWhere) - 5
    If lngLen <= 0 Then     'Nah: there was nothing in the string.
        MsgBox "No criteria", vbInformation, "Nothing to do."
    Else                    'Yep: there is something there, so remove the " AND " at the end.
        strWhere = Left$(strWhere, lngLen)
        'For debugging, remove the leading quote on the next line. Prints to Immediate Window (Ctrl+G).
        Debug.Print strWhere
     
        'Finally, apply the string as the form's Filter.
     
        Me.Filter = strWhere
        Me.FilterOn = True
    End If
End Sub

Private Sub cmdReset_Click()
    'Purpose:   Clear all the search boxes in the Form Header, and show all records again.
    Dim ctl As Control
 
    'Clear all the controls in the Form Header section.
    For Each ctl In Me.Section(acHeader).Controls
        Select Case ctl.ControlType
        Case acTextBox, acComboBox, acCheckBox
            ctl.Value = Null
        'Case acCheckBox
            'ctl.Value = False
        End Select
    Next
 
    'Remove the form's filter.
    Me.FilterOn = False
End Sub

Mod Edit: Used proper code tags for ease of reading.
Hi. Thanks for posting your code. You should be able to simply use Me.Filter to get the criteria you want for your report now. For example:
Code:
DoCmd.OpenReport "ReportName", acViewPreview, , Me.Filter
Hope that helps...
 

mounty76

Registered User.
Local time
Today, 13:57
Joined
Sep 14, 2017
Messages
341
OK great, thank you, is it possible to have something as simple as the above to put the data into a temp table? I'll need to be able to run queries off it as well for sum totals etc.
 

theDBguy

I’m here to help
Staff member
Local time
Today, 13:57
Joined
Oct 29, 2018
Messages
21,473
OK great, thank you, is it possible to have something as simple as the above to put the data into a temp table? I'll need to be able to run queries off it as well for sum totals etc.
What is the Record Source of your Form?
 

theDBguy

I’m here to help
Staff member
Local time
Today, 13:57
Joined
Oct 29, 2018
Messages
21,473
A table called Accounts
Okay, you could try using:
Code:
CurrentDb.Execute "SELECT * INTO TempTable FROM Accounts WHERE " & Me.Filter, dbFailOnError
Hope that helps...
 

mounty76

Registered User.
Local time
Today, 13:57
Joined
Sep 14, 2017
Messages
341
Says "Multi Value Fields are not allowed in SELECT INTO statements"
 

theDBguy

I’m here to help
Staff member
Local time
Today, 13:57
Joined
Oct 29, 2018
Messages
21,473
Says "Multi Value Fields are not allowed in SELECT INTO statements"
That's correct! So, to answer your question in post #6 about using a "simple" approach to create that temp table, the answer would a "no, there's simple way."

If you must include the MVF in the temp table, you could take a look at this demo and see if it helps.

 

mounty76

Registered User.
Local time
Today, 13:57
Joined
Sep 14, 2017
Messages
341
Ah! the MVF db comes up with an error when trying it.

The db I took the original search form also has a query that is linked to the search but I cannot seem to get it to work on my db, the SQL I have is



PARAMETERS [Forms]![frmAccountSearch]![cboFilterCode] Short, [Forms]![frmAccountSearch]![txtFilterSupplier] Long, [Forms]![frmAccountSearch]![txtStartDate] DateTime, [Forms]![frmAccountSearch]![txtFilterEndDate] DateTime;
SELECT Accounts.*
FROM Accounts
WHERE IIf([Forms]![frmAccountSearch]![cboFilterCode] = -1, (Accounts.Code),
IIf([Forms]![frmAccountSearch]![cboFilterCode] = 0, (NOT Accounts.Code), True))
AND (([Forms]![frmAccountSearch]![txtFilterSupplier] Is Null)
OR (Accounts.Supplier Like "*" & [Forms]![frmAccountSearch]![txtFilterSupplier] & "*"))
AND (([Forms]![frmAccountSearch]![txtFilterDesc] Is Null)
OR (Accounts.Description = [Forms]![frmAccountSearch]![txtFilterDesc]))
AND (([Forms]![frmAccountSearch]![txtStartDate] Is Null)
OR (Accounts.Date >= [Forms]![frmAccountSearch]![txtStartDate]))
AND (([Forms]![frmAccountSearch]![txtFilterEndDate] Is Null)
OR (Accounts.Date < DateAdd("d", 1, [Forms]![frmAccountSearch]![txtFilterEndDate])));

 

theDBguy

I’m here to help
Staff member
Local time
Today, 13:57
Joined
Oct 29, 2018
Messages
21,473
Ah! the MVF db comes up with an error when trying it.
What was the error? Can't help you, if we don't know what's happening.
The db I took the original search form also has a query that is linked to the search but I cannot seem to get it to work on my db, the SQL I have is
I also don't understand this part. Which db is that?
 

mounty76

Registered User.
Local time
Today, 13:57
Joined
Sep 14, 2017
Messages
341
1605215467515.png
 

mounty76

Registered User.
Local time
Today, 13:57
Joined
Sep 14, 2017
Messages
341
Attached is the original db that I took the search function from
 

Attachments

  • search2000.mdb
    356 KB · Views: 94

theDBguy

I’m here to help
Staff member
Local time
Today, 13:57
Joined
Oct 29, 2018
Messages
21,473
Attached is the original db that I took the search function from
Don't think that will help us help you since that demo, presumably, works on its own. If you're having problems implementing it into your own db, we'll need to see your db, to help you figure out what went wrong.
 

Gasman

Enthusiastic Amateur
Local time
Today, 21:57
Joined
Sep 21, 2011
Messages
14,298
Ah! the MVF db comes up with an error when trying it.

The db I took the original search form also has a query that is linked to the search but I cannot seem to get it to work on my db, the SQL I have is



PARAMETERS [Forms]![frmAccountSearch]![cboFilterCode] Short, [Forms]![frmAccountSearch]![txtFilterSupplier] Long, [Forms]![frmAccountSearch]![txtStartDate] DateTime, [Forms]![frmAccountSearch]![txtFilterEndDate] DateTime;
SELECT Accounts.*
FROM Accounts
WHERE IIf([Forms]![frmAccountSearch]![cboFilterCode] = -1, (Accounts.Code),
IIf([Forms]![frmAccountSearch]![cboFilterCode] = 0, (NOT Accounts.Code), True))
AND (([Forms]![frmAccountSearch]![txtFilterSupplier] Is Null)
OR (Accounts.Supplier Like "*" & [Forms]![frmAccountSearch]![txtFilterSupplier] & "*"))
AND (([Forms]![frmAccountSearch]![txtFilterDesc] Is Null)
OR (Accounts.Description = [Forms]![frmAccountSearch]![txtFilterDesc]))
AND (([Forms]![frmAccountSearch]![txtStartDate] Is Null)
OR (Accounts.Date >= [Forms]![frmAccountSearch]![txtStartDate]))
AND (([Forms]![frmAccountSearch]![txtFilterEndDate] Is Null)
OR (Accounts.Date < DateAdd("d", 1, [Forms]![frmAccountSearch]![txtFilterEndDate])));

@mounty76 I appreciate you are now using code tags, but the General option is enough. That shows the code much better, as below.?
I even do mine by just surrounding the code with code and /code and both those words are enclosed with square parentheses. [ & ]

Code:
PARAMETERS [Forms]![frmAccountSearch]![cboFilterCode] Short, [Forms]![frmAccountSearch]![txtFilterSupplier] Long, [Forms]![frmAccountSearch]![txtStartDate] DateTime, [Forms]![frmAccountSearch]![txtFilterEndDate] DateTime;
SELECT Accounts.*
FROM Accounts
WHERE IIf([Forms]![frmAccountSearch]![cboFilterCode] = -1, (Accounts.Code),
    IIf([Forms]![frmAccountSearch]![cboFilterCode] = 0, (NOT Accounts.Code), True))
  AND (([Forms]![frmAccountSearch]![txtFilterSupplier] Is Null)
    OR (Accounts.Supplier Like "*" & [Forms]![frmAccountSearch]![txtFilterSupplier] & "*"))
  AND (([Forms]![frmAccountSearch]![txtFilterDesc] Is Null)
    OR (Accounts.Description = [Forms]![frmAccountSearch]![txtFilterDesc]))
  AND (([Forms]![frmAccountSearch]![txtStartDate] Is Null)
    OR (Accounts.Date >= [Forms]![frmAccountSearch]![txtStartDate]))
AND (([Forms]![frmAccountSearch]![txtFilterEndDate] Is Null)
    OR (Accounts.Date < DateAdd("d", 1, [Forms]![frmAccountSearch]![txtFilterEndDate])));
 

mounty76

Registered User.
Local time
Today, 13:57
Joined
Sep 14, 2017
Messages
341
Hi Guys,

Problem solved, I've removed the attachment field from the DB, didn't really need it in there anyway so easier to do that, now the simple one liner works great.

Thanks again and have a great day
 

theDBguy

I’m here to help
Staff member
Local time
Today, 13:57
Joined
Oct 29, 2018
Messages
21,473
Hi Guys,

Problem solved, I've removed the attachment field from the DB, didn't really need it in there anyway so easier to do that, now the simple one liner works great.

Thanks again and have a great day
Hi. Glad to hear you got it sorted out. Good luck with your project.
 

Users who are viewing this thread

Top Bottom