Results 1 to 5 of 5
  1. #1
    Gina Maylone is offline Always learning
    Windows 7 64bit Access 2013
    Join Date
    Jun 2013
    Location
    Afton, MN
    Posts
    544

    Apply filter issues

    smallquickquotepro.zip

    Hello all, this is somewhat related to my previous posts regarding Filtering by Subform's Field Values, which I have managed a work around by creating a form (GoBid)based on a query (2contactsandbids). On my form I have 3 search fields, statusfilter, bidderfilter, biddatefilter. I am using the following to filter the records:
    Code:
    Private Sub search_click()
    On Error GoTo errHandler
    If Not IsNull(Me.statusfilter) And IsNull(Me.bidderfilter) And IsNull(Me.biddatefilter) Then
    DoCmd.ApplyFilter "statusfilterquery"
    End If
    If Not IsNull(Me.statusfilter) And Not IsNull(Me.bidderfilter) And IsNull(Me.biddatefilter) Then
    DoCmd.ApplyFilter "bidderstatusquery"
    End If
    If Not IsNull(Me.statusfilter) And IsNull(Me.bidderfilter) And Not IsNull(Me.biddatefilter) Then
    DoCmd.ApplyFilter "statusbiddatequery"
    End If
    If IsNull(Me.statusfilter) And IsNull(Me.bidderfilter) And Not IsNull(Me.biddatefilter) Then
    DoCmd.ApplyFilter "biddatequery"
    End If
    If IsNull(Me.statusfilter) And Not IsNull(Me.bidderfilter) And Not IsNull(Me.biddatefilter) Then
    DoCmd.ApplyFilter "biddatebidderquery"
    End If
    If IsNull(Me.statusfilter) And Not IsNull(Me.bidderfilter) And IsNull(Me.biddatefilter) Then
    DoCmd.ApplyFilter "bidderquery"
    End If
    If Not IsNull(Me.statusfilter) And Not IsNull(Me.bidderfilter) And Not IsNull(Me.biddatefilter) Then
    DoCmd.ApplyFilter "allquery"
    Debug.Print filter
    End If
    Exit Sub
    errHandler:
        MsgBox "Error " & Err.Number & ": " & Err.Description & " in " & _
               VBE.ActiveCodePane.CodeModule, vbOKOnly, "Error"
    End Sub
    It works awesome the first time I run it, but after clearing the filter and re-filtering I get a runtime error 3071 the expression is typed incorrectly, or it is too complex to be evaluated, highlight is at "DoCmd.ApplyFilter "allquery" The SQL forallquery is:

    Code:
    SELECT [2contactsandbids].FullName, [2contactsandbids].fulladdress, [2contactsandbids].BidDate, [2contactsandbids].Status, [2contactsandbids].Bidder
    FROM 2contactsandbids
    WHERE ((([2contactsandbids].BidDate)=Format([forms]![gobid]![biddatefilter],"mm/dd/yy")) AND (([2contactsandbids].Status)=[forms]![gobid]![statusfilter]) AND (([2contactsandbids].Bidder)=[forms]![gobid]![bidderfilter]));
    IF I enter criteria in all 3 search fields, it works fine, but when I enter only status=Pending and bidder=Sam Anderson, I get the error. My IF statement continues to the last line, instead of stopping at the "bidderstatus" line. I've tried ElseIf's with no luck.



    Thank you in advance for another set of eyes.

  2. #2
    June7's Avatar
    June7 is offline VIP
    Windows 7 64bit Access 2010 32bit
    Join Date
    May 2011
    Location
    The Great Land
    Posts
    53,770
    I have never used ApplyFilter. I construct filter string and set form Filter and FilterOn properties. http://www.allenbrowne.com/ser-62.html

    And I NEVER use dynamic parameters in a query WHERE clause.
    How to attach file: http://www.accessforums.net/showthread.php?t=70301 To provide db: copy, remove confidential data, run compact & repair, zip w/Windows Compression.

  3. #3
    Gina Maylone is offline Always learning
    Windows 7 64bit Access 2013
    Join Date
    Jun 2013
    Location
    Afton, MN
    Posts
    544
    Hi again June7. Thanks for the feedback. I have successfully used dynamic parameters in a query where clause many times. I have heeded your advice though and am back to using Allen Browne's code for multiple criteria and am getting an error 3075 Extra ) in query expression '([status]="Pending") AND ([bidder]="") And ([biddate]=)' and when I open the form in design view after clearing the filter, the previous filter is still there ([status] = "") AND ([bidder] = "Sam Anderson") AND ([biddate] = ).
    Code:
    On Error Resume Next
    On Error GoTo errHandler
    'Purpose:   This module illustrates how to create a search form, _
                where the user can enter as many or few criteria as they wish, _
                and results are shown one per line.
    'Note:      Only records matching ALL of the criteria are returned.
    'Author:    AlLeng Browne (alLeng@alLengbrowne.com), June 2006.
    
        '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 lngLeng As Long                      'Lenggth 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.statusfilter) Then
            strWhere = strWhere & "([status] = """ & Me.statusfilter & """) AND "
        End If
        If Not IsNull(Me.bidderfilter) Then
            strWhere = strWhere & "([bidder] = """ & Me.bidderfilter & """) AND "
        End If
        If Not IsNull(Me.biddatefilter) Then
           strWhere = strWhere & "([biddate] = " & Format(Me.biddatefilter, 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.
        lngLeng = Len(strWhere) - 5
        If lngLeng <= 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, lngLeng)
            '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
        Debug.Print strWhere
        Exit Sub
    errHandler:
        MsgBox "Error " & Err.Number & ": " & Err.Description & " in " & _
               VBE.ActiveCodePane.CodeModule, vbOKOnly, "Error"
    End Sub
    And then
    Code:
    debug.Print strwhere
    ([status] = "Needs Bid") AND ([bidder] = "") AND ([biddate] = )

  4. #4
    June7's Avatar
    June7 is offline VIP
    Windows 7 64bit Access 2010 32bit
    Join Date
    May 2011
    Location
    The Great Land
    Posts
    53,770
    The code is testing for Null in controls. Apparently your controls have an empty string. Can handle both with:

    If Me.biddatefilter & "" <> "" Then
    How to attach file: http://www.accessforums.net/showthread.php?t=70301 To provide db: copy, remove confidential data, run compact & repair, zip w/Windows Compression.

  5. #5
    Gina Maylone is offline Always learning
    Windows 7 64bit Access 2013
    Join Date
    Jun 2013
    Location
    Afton, MN
    Posts
    544
    BINGO! That seems to have done the trick! THANK YOU THANK YOU THANK YOU!!!!

Please reply to this thread with any new information or opinions.

Similar Threads

  1. Filter By Form and Apply Filter Buttons
    By JustLearning in forum Forms
    Replies: 13
    Last Post: 02-18-2015, 01:01 PM
  2. Replies: 2
    Last Post: 02-25-2013, 10:47 AM
  3. Replies: 5
    Last Post: 02-07-2013, 12:21 PM
  4. Apply Filter similar to Field Filter
    By DatabaseIntern in forum Forms
    Replies: 1
    Last Post: 06-11-2012, 05:42 PM
  5. How to filter dates using an apply filter code.
    By Jgreenfield in forum Reports
    Replies: 4
    Last Post: 11-15-2011, 01:38 PM

Tags for this Thread

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •  
Other Forums: Microsoft Office Forums