Page 1 of 2 12 LastLast
Results 1 to 15 of 16
  1. #1
    gint32 is offline Competent Performer
    Windows 7 64bit Access 2013
    Join Date
    Jan 2015
    Location
    Australia
    Posts
    116

    Thumbs up sql creates a parameter rather than a criteria


    Hi Everyone,

    Can Anyone explain to me where I am going wrong, I am having some great difficulty with a query named "qry_Query1" that gets recreated using the below code.
    I have a form with a combox that selects a value then actions on the event with the below code to filter records based on the value the users selects, sounds simple enough, but instead of getting any results I end up creating a parameter query as below:
    Anyone that can throw some light on my VBA Sql errors I would be most grateful.

    The VBA code I have so far is as follows"

    Code:
    Private Sub Command7_Click() 
    Dim db As DAO.Database
    Dim qd As QueryDef
    Dim vWhere As Variant
    Stop
    Set db = CurrentDb()
    
    On Error Resume Next
    db.QueryDefs.Delete "qry_Query1"
    On Error GoTo 0
    
    vWhere = Null
    
    'Apptsurname = field
    
    vWhere = vWhere & " AND ApptSurname=" + Me.cboPayeeID   '''selected combobox value 
    
     Set qd = db.CreateQueryDef("qry_Query1", "SELECT * FROM tblAppointments WHERE " & _
        Mid(vWhere, 6)) 
    
        db.Close
        Set db = Nothing
        Stop
        DoCmd.OpenQuery "qry_Query1", acViewNormal, acReadOnly
    End If
    End Sub
    This is the sql of qry_Query1
    Code:
    SELECT *
    FROM tblAppointments
    WHERE (((tblAppointments.[ApptSurname])=[Smith]));
    Below is what I would like to achieve but without any success for "qry_Query1"

    Code:
    SELECT *
    FROM tblAppointments
    WHERE (((tblAppointments.[ApptSurname])="Smith"));

  2. #2
    Micron is offline Very Inert Person
    Windows 7 32bit Access 2007
    Join Date
    Jun 2014
    Location
    Ontario, Canada
    Posts
    13,423
    Looks to me like you are attempting to do way too much for the goal at hand. That is, to filter a form that is already open? I can assist with the sql statement, but have to wonder why you're creating an AND parameter, then ignoring it with the Mid function. For what you are doing, the + sign is also a no-no. You might also be mixing the payee id and surname as different data types?
    The more we hear silence, the more we begin to think about our value in this universe.
    Paraphrase of Professor Brian Cox.

  3. #3
    gint32 is offline Competent Performer
    Windows 7 64bit Access 2013
    Join Date
    Jan 2015
    Location
    Australia
    Posts
    116
    Sorry, I should have mentioned in the first post, this code is begged, stole and amended from doctor Google.Com:

    So, the reference to Me.cboPayeeID is actually not to an Id (any longer) it actually refers to a selected text value, nad in the case of the examples I gave above "Smith"


    In short, I just need help with getting rid of the Parameters as I said.

    I have "No idea: as to what the Mid is actually doing, if i did then i probably wouldn't need any help

    Thanks anyway, for your input

  4. #4
    gint32 is offline Competent Performer
    Windows 7 64bit Access 2013
    Join Date
    Jan 2015
    Location
    Australia
    Posts
    116
    Quote Originally Posted by Micron View Post
    Looks to me like you are attempting to do way too much for the goal at hand. That is, to filter a form that is already open? I can assist with the sql statement, but have to wonder why you're creating an AND parameter, then ignoring it with the Mid function. For what you are doing, the + sign is also a no-no. You might also be mixing the payee id and surname as different data types?
    So in essence are you saying if I get rid of the AND part in the example code supplied then I will loose the parameter in the query and it'll work the way I wish is to work
    as in
    Code:
    SELECT *
    FROM tblAppointments
    WHERE (((tblAppointments.[ApptSurname])="Smith"));

  5. #5
    Micron is offline Very Inert Person
    Windows 7 32bit Access 2007
    Join Date
    Jun 2014
    Location
    Ontario, Canada
    Posts
    13,423
    Well, you didn't tell me what the sql statement is for. Assuming it is to apply a filter to the existing form, since you appear to be running it off of a command button, this would suffice:
    Code:
    Private Sub Command7_Click() 
    
    Me.Filter = "SELECT * FROM tblAppointments WHERE tblAppointments.[ApptSurname]='" & Me.cboPayeeID & "'"
    Me.FilterOn = True
    
    End Sub
    Since you've stated the combo is now providing a text value, the combo value is wrapped in single quotes. If the combo field is no longer looking at the name field (as opposed to maybe the record ID field), you'll have to change my reference to the correct field name.
    It is also possible to apply this filter after the combo box selection, but you'd have to provide more info as to what exactly you are attempting to do. Even if this is to open another form based on a sql statement, you still have way too much code, but what I provided won't do that either. There is also no provision for removing the filter once it has been applied.

    If all you want is to eliminate the prompt, the sql syntax I posted should take care of that, as long as all the name references are correct. If it doesn't do the trick, you'll have to provide more info about that prompt.

    EDIT
    So in essence are you saying if I get rid of the AND part in the example code supplied then I will loose the parameter in the query and it'll work the way I wish is to work
    as in
    I think so, as long as the name references are correct and you concatenate (not add + ) the necessary parts.
    Last edited by Micron; 12-17-2016 at 02:39 PM. Reason: incomplete answer
    The more we hear silence, the more we begin to think about our value in this universe.
    Paraphrase of Professor Brian Cox.

  6. #6
    gint32 is offline Competent Performer
    Windows 7 64bit Access 2013
    Join Date
    Jan 2015
    Location
    Australia
    Posts
    116

    Now: Totally lost

    I'll try and explain again:
    the code as follows(to which i have no idea as to how it works....novice )


    Gives me .....A query

    Code:
    SELECT *
    FROM tblAppointments
    WHERE (((tblAppointments.[ApptSurname])=[Smith]));
    "All" I am asking for is help Changing the VBA/SQL Code so as it doesn't give the above but gives the below

    Code:
    SELECT *
    FROM tblAppointments
    WHERE (((tblAppointments.[ApptSurname])="Smith"));
    Don't ask me how or why it does this, As I have no idea, all I know is I just need to change it from a parameter query top to the above example!!!
    Hope fully this will make more sense.


    Code:
    Private Sub Command7_Click() 
    Dim db As DAO.Database
    Dim qd As QueryDef
    Dim vWhere As Variant
    Stop
    Set db = CurrentDb()
    
    On Error Resume Next
    db.QueryDefs.Delete "qry_Query1"
    On Error GoTo 0
    
    vWhere = Null
    
    'Apptsurname = field
    
    vWhere = vWhere & " AND ApptSurname=" + Me.cboPayeeID   '''selected combobox value 
    
     Set qd = db.CreateQueryDef("qry_Query1", "SELECT * FROM tblAppointments WHERE " & _
        Mid(vWhere, 6)) 
    
        db.Close
        Set db = Nothing
        Stop
        DoCmd.OpenQuery "qry_Query1", acViewNormal, acReadOnly
    End If
    End Sub

  7. #7
    aytee111 is offline Competent At Times
    Windows 7 32bit Access 2013 32bit
    Join Date
    Nov 2011
    Location
    Nomad
    Posts
    3,936
    Code:
    Dim qdf As QueryDef, vWhere as string
    Set qdf = CurrentDb.QueryDefs("qry_Query1")
    vWhere = " AND ApptSurname=" + Me.cboPayeeID
    qdf.SQL = SELECT * FROM tblAppointments WHERE (((tblAppointments.[ApptSurname])='" & Mid(vWhere, 6) & "'));"
    Set qdf = Nothing
    DoCmd.OpenQuery "qry_Query1"
    Not too sure how to get the surname - fix code as necessary.
    Last edited by aytee111; 12-17-2016 at 04:25 PM. Reason: Edited per Micron's post

  8. #8
    Micron is offline Very Inert Person
    Windows 7 32bit Access 2007
    Join Date
    Jun 2014
    Location
    Ontario, Canada
    Posts
    13,423
    sorry to not comprehend, but I don't see any difference between
    Code:
    SELECT * FROM tblAppointments
    WHERE (((tblAppointments.[ApptSurname])=[Smith]));
    and
    Code:
    SELECT *
    FROM tblAppointments
    WHERE (((tblAppointments.[ApptSurname])="Smith"));
    Nor do I see what makes your query prompt for a parameter, unless as I've already noted, there is a disconnect between what your query expects and the reference you are using to pass the person's name to your query. You can try the sql I already created for you, as in
    Code:
    Set qd = db.CreateQueryDef("qry_Query1", "SELECT * FROM tblAppointments WHERE tblAppointments.[ApptSurname]='" & Me.cboPayeeID & "'")
    As long as the combo box is providing a text value and not some number. Again, the whole thing looks overblown - like killing a fly with a sledgehammer.

    aytee111: Smith is just an example as per post #3. The name has to come from the combo box (unless I'm totally off base).

  9. #9
    gint32 is offline Competent Performer
    Windows 7 64bit Access 2013
    Join Date
    Jan 2015
    Location
    Australia
    Posts
    116
    Quote Originally Posted by aytee111 View Post
    Code:
    Dim qdf As QueryDef, vWhere as string
    Set qdf = CurrentDb.QueryDefs("qry_Query1")
    vWhere = " AND ApptSurname=" + Me.cboPayeeID
    qdf.SQL = SELECT * FROM tblAppointments WHERE (((tblAppointments.[ApptSurname])='" & Mid(vWhere, 6) & "'));"
    Set qdf = Nothing
    DoCmd.OpenQuery "qry_Query1"
    Not too sure how to get the surname - fix code as necessary.
    Thanks for you and everyone's input, but when I copy and paste over I get syntax error on this line

    Code:
    qdf.SQL = SELECT * FROM tblAppointments WHERE (((tblAppointments.[ApptSurname])='" & Mid(vWhere, 6) & "'));"

  10. #10
    gint32 is offline Competent Performer
    Windows 7 64bit Access 2013
    Join Date
    Jan 2015
    Location
    Australia
    Posts
    116
    Quote Originally Posted by Micron View Post
    sorry to not comprehend, but I don't see any difference between
    Code:
    SELECT * FROM tblAppointments
    WHERE (((tblAppointments.[ApptSurname])=[Smith]));
    and
    Code:
    SELECT *
    FROM tblAppointments
    WHERE (((tblAppointments.[ApptSurname])="Smith"));
    Nor do I see what makes your query prompt for a parameter, unless as I've already noted, there is a disconnect between what your query expects and the reference you are using to pass the person's name to your query. You can try the sql I already created for you, as in
    Code:
    Set qd = db.CreateQueryDef("qry_Query1", "SELECT * FROM tblAppointments WHERE tblAppointments.[ApptSurname]='" & Me.cboPayeeID & "'")
    As long as the combo box is providing a text value and not some number. Again, the whole thing looks overblown - like killing a fly with a sledgehammer.

    aytee111: Smith is just an example as per post #3. The name has to come from the combo box (unless I'm totally off base).
    Hi, Sorry the difference between the 1st SQL example and the second is 1st = [parameter] and the other looks for criteria "value", So I am trying to lose the [] and instead get "" from my sub

  11. #11
    Micron is offline Very Inert Person
    Windows 7 32bit Access 2007
    Join Date
    Jun 2014
    Location
    Ontario, Canada
    Posts
    13,423
    Code:
    I am trying to lose the []
    I can't believe I didn't see that - and I missed it even without imbibing. I guess it was just too late at night.

    Yes, the [] will prompt you because that is how you'd specify a field, and Access would want to know what that is since it can't figure it out. As for your most recent issue, the string you are passing to the variable has to be entirely wrapped in quotes OR the concatenated parts each have to be wrapped in quotes. If how you posted it is how you really have it, I'd say that's the immediate issue.
    "SELECT * FROM tblAppointments WHERE (((tblAppointments.[ApptSurname])='" & Mid(vWhere, 6) & "'));"
    As I mentioned before, I suspect this will still not work because of your vWhere part. That will include a solitary " (after ApptSurname), plus you are using an arithmetic operator when you should not be. The solution for this was already posted by me, if I recall.
    The more we hear silence, the more we begin to think about our value in this universe.
    Paraphrase of Professor Brian Cox.

  12. #12
    aytee111 is offline Competent At Times
    Windows 7 32bit Access 2013 32bit
    Join Date
    Nov 2011
    Location
    Nomad
    Posts
    3,936
    Missing the beginning quote, my bad. As stated previously, vWhere is an unknown variable.

    Code:
    qdf.SQL = "SELECT * FROM tblAppointments WHERE (((tblAppointments.[ApptSurname])='" & Mid(vWhere, 6) & "'));"

  13. #13
    Micron is offline Very Inert Person
    Windows 7 32bit Access 2007
    Join Date
    Jun 2014
    Location
    Ontario, Canada
    Posts
    13,423
    Forget the notion that a double quote will be included.

  14. #14
    ssanfu is offline Master of Nothing
    Windows XP Access 2010 32bit
    Join Date
    Sep 2010
    Location
    Anchorage, Alaska, USA
    Posts
    9,664
    Quote Originally Posted by gint32 View Post
    I have "No idea: as to what the Mid is actually doing, if i did then i probably wouldn't need any help
    This is what the Mid() function does: The Mid() function copies a sub-string of the specified string starting at the "start" character for "length" characters.
    If the "length" value is missing, then the sub-string copied is from the "start" character to the end of the string.

    --------
    From HELP:
    Mid Function
    : Returns a Variant (String) containing a specified number of characters from a string.
    Syntax: Mid(string, start[, length])
    where
    string Required.
    start Required
    length Optional; Variant (Long).
    --------

    Example: Mid("John Wilkes Booth", 6, 6) returns "Wilkes"
    Example: Mid("John Wilkes Booth", 6) returns "Wilkes Booth" '<-- because of the missing optional length parameter


    You have
    Code:
    vWhere = vWhere & " AND ApptSurname='" & Me.cboPayeeID & "'"
    
     Set qd = db.CreateQueryDef("qry_Query1", "SELECT * FROM tblAppointments WHERE " & Mid(vWhere, 6))
    If vWhere = " AND ApptSurname= 'Smith'", then
    Mid(vWhere, 6) is equal to "ApptSurname= 'Smith'"

    The Mid() function copies the string at character #6 until the end of the string.
    This results in removing the leading space, the word AND and the trailing space in your variable "vWhere".



    Since you only have one criteria, you don't need " AND " in your string..... then you don't need the Mid() function!
    Code:
    vWhere = vWhere & "ApptSurname='" & Me.cboPayeeID & "'"
    
     Set qd = db.CreateQueryDef("qry_Query1", "SELECT * FROM tblAppointments WHERE " & vWhere)

  15. #15
    Micron is offline Very Inert Person
    Windows 7 32bit Access 2007
    Join Date
    Jun 2014
    Location
    Ontario, Canada
    Posts
    13,423
    I don't get why it's assigned to vWhere at all. That assignment comes from a reference to a form control. I used that reference in post #5 and noted it should work as written as long as the control was returning text and not a number as cboPayeeID suggests it is.

    Me.Filter = "SELECT * FROM tblAppointments WHERE tblAppointments.[ApptSurname]='" & Me.cboPayeeID & "'"
    Kudos for you for taking the time to explain the Mid function!

Page 1 of 2 12 LastLast
Please reply to this thread with any new information or opinions.

Similar Threads

  1. Yes/No parameter that dictates a criteria
    By mcgarr423 in forum Queries
    Replies: 1
    Last Post: 11-02-2016, 01:39 PM
  2. Replies: 3
    Last Post: 08-15-2015, 01:16 AM
  3. Use Parameter Criteria in a Report HELP!
    By newbie in forum Reports
    Replies: 4
    Last Post: 04-18-2014, 12:17 PM
  4. Parameter with Month & Year Criteria
    By Huddle in forum Access
    Replies: 3
    Last Post: 10-24-2012, 01:20 PM
  5. Criteria Parameter
    By djwasim in forum Reports
    Replies: 1
    Last Post: 07-04-2009, 08:22 AM

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