Results 1 to 14 of 14
  1. #1
    akel210 is offline Novice
    Windows 7 64bit Access 2003
    Join Date
    Feb 2011
    Posts
    4

    running multiple update queries with one command, query, etc

    Hi people. I need urgent help.
    I have many update queries in access 2003. I have to run all the times and I would to create SQL, VBA or combination of both to create a process where I can do this by just one query, button, function etc. I can't do this in a macro because the list of these update queries can increase or decrease at anytime and then I would have to update the macro. It defeats the purpose. All of these queries start with common name "0010 01....."

    I want something where it says look up queries if it starts with “0070 01” then Run it.
    Using this following SQL

    SELECT Name
    FROM MSysObjects
    WHERE Name Like "0010 01*";

    I can come up with the list of queries but i am not sure how utilize this into VBA or anywhere else to automate the process to meet my requirements.
    Like I said earlier I want something where it says look up queries if it starts with “0070 01” then Run it. I am open to other options if you have any.

    Please help me! Thanks in advance

  2. #2
    pbaldy's Avatar
    pbaldy is offline Who is John Galt?
    Windows XP Access 2007
    Join Date
    Feb 2010
    Location
    Nevada, USA
    Posts
    22,521
    You could open a recordset on that SQL and use the name along with CurrentDb.Execute or DoCmd.OpenQuery inside a loop of the results.
    Paul (wino moderator)
    MS Access MVP 2007-2019
    www.BaldyWeb.com

  3. #3
    pkstormy's Avatar
    pkstormy is offline Access/SQL Server Expert
    Windows XP Access 2003
    Join Date
    Mar 2010
    Location
    Madison
    Posts
    682
    An example (in ADO - someone else can supply the DAO code - I use ADO myself):

    Function runQueries()
    dim rs as adodb.recordset
    set rs = new adodb.recordset
    dim strSQL as string
    strSQL = "SELECT Name FROM MSysObjects WHERE Name Like '0010 01*'"

    (note: if the above syntax doesn't work, you can also create a query using the above, save it as qryMyQueriesToRun, and then...
    strSQL = "Select * from qryMyQueriesToRun"

    rs.open strSQL, currentproject.connection, adopenkeyset, adlockreadonly
    if rs.eof and rs.bof then
    rs.close
    set rs = nothing
    msgbox "No queries to run."
    exit function
    end if
    rs.movefirst
    do while not rs.eof
    docmd.setwarnings False 'optional - if used you MUST turn warnings back on when done!!, comment out for testing.
    msgbox "About to execute query name: " & rs!Name '(for testing. Comment out when live)
    docmd.openquery """ & rs!Name & """ '(not sure about this syntax - maybe no " used)
    docmd.setwarnings True
    rs.movenext
    loop
    rs.close
    set rs = nothing
    exit function

    Save this in a module. Then in your OnClick code for a button on the form (or wherever), put in code: Call RunQueries

  4. #4
    ssanfu is offline Master of Nothing
    Windows 2K Access 2000
    Join Date
    Sep 2010
    Location
    Anchorage, Alaska, USA
    Posts
    9,664
    Here is a DAO version:

    Code:
    Sub runQueries()
       Dim db As DAO.Database
       Dim rs As DAO.Recordset
       Dim strSQL As String
    
       Set db = CurrentDb
       strSQL = "SELECT Name FROM MSysObjects WHERE Name Like '0010 01*'"
    
       ' sorted order - 
       '       if the queries execute in a specific order set by query name
       '   strSQL = "SELECT MSysObjects.Name"
       '   strSQL = strSQL & " FROM MSysObjects"
       '   strSQL = strSQL & " WHERE (((MSysObjects.Name) Like '0010 01*'))"
       '   strSQL = strSQL & " ORDER BY MSysObjects.Name;"
    
       Set rs = db.OpenRecordset(strSQL)
       If rs.BOF And rs.EOF Then
          rs.Close
          Set rs = Nothing
          MsgBox "No queries to run."
       Else
          rs.MoveLast
          rs.MoveFirst
          Do While Not rs.EOF
             MsgBox "About to execute query name: " & rs!Name   '(for testing. Comment out when live)
             CurrentDb.Execute rs!Name, dbFailOnError
             rs.MoveNext
          Loop
       End If
    
       rs.Close
       Set rs = Nothing
       Set db = Nothing
       MsgBox "Done"
    
    End Sub

  5. #5
    akel210 is offline Novice
    Windows 7 32bit Access 2003
    Join Date
    Feb 2011
    Posts
    4
    Thank You guys!! even with my limited skills of SQL and VBA it worked perfectly. I created a button iin the form and pasted the code and it worked! the only question is can i use this code in a query? if yes how?

    another thing is that I wasn't prompted with Update query prompts where it says " you are about to run an update query............" "x number of records will be updated", if i want to turn these on what modification do i need in the code?

    you guys are wonderful! thanks!

  6. #6
    pkstormy's Avatar
    pkstormy is offline Access/SQL Server Expert
    Windows XP Access 2003
    Join Date
    Mar 2010
    Location
    Madison
    Posts
    682
    Quote Originally Posted by akel210 View Post
    the only question is can i use this code in a query? if yes how?
    Do you mean copy the "SELECT Name FROM MSysObjects WHERE Name Like '0010 01*" into a query? - Yes. But you can't automate running other queries inside a query. You must use vba (or a macro) to automate the running of a query(s).

    Quote Originally Posted by akel210 View Post
    another thing is that I wasn't prompted with Update query prompts where it says " you are about to run an update query............" "x number of records will be updated", if i want to turn these on what modification do i need in the code?
    Comment out or delete the line that is: Docmd.SetWarnings False

  7. #7
    akel210 is offline Novice
    Windows 7 32bit Access 2003
    Join Date
    Feb 2011
    Posts
    4
    pkstormy, I used DAO version provided by ssanfu and in his verision doesn't have the "Docmd.SetWarnings False" line.

    And I tired deleting this line from DAO code
    MsgBox "About to execute query name: " & rs!Name '(for testing. Comment out when live)

    But this doesn't show the prompt box for the update queries. by deleting this line i just don't see the message "About to execute query name...."

    any other idea or I am doing it wrong?

    thanks,

  8. #8
    pbaldy's Avatar
    pbaldy is offline Who is John Galt?
    Windows XP Access 2007
    Join Date
    Feb 2010
    Location
    Nevada, USA
    Posts
    22,521
    CurrentDb.Execute does not throw those warnings. If you really want them, you can switch to DoCmd.OpenQuery
    Paul (wino moderator)
    MS Access MVP 2007-2019
    www.BaldyWeb.com

  9. #9
    pkstormy's Avatar
    pkstormy is offline Access/SQL Server Expert
    Windows XP Access 2003
    Join Date
    Mar 2010
    Location
    Madison
    Posts
    682
    Thanks Paul.

  10. #10
    pbaldy's Avatar
    pbaldy is offline Who is John Galt?
    Windows XP Access 2007
    Join Date
    Feb 2010
    Location
    Nevada, USA
    Posts
    22,521
    No problemo.
    Paul (wino moderator)
    MS Access MVP 2007-2019
    www.BaldyWeb.com

  11. #11
    ssanfu is offline Master of Nothing
    Windows 2K Access 2000
    Join Date
    Sep 2010
    Location
    Anchorage, Alaska, USA
    Posts
    9,664
    Quote Originally Posted by akel210 View Post
    pkstormy, I used DAO version provided by ssanfu and in his verision doesn't have the "Docmd.SetWarnings False" line.

    And I tired deleting this line from DAO code
    MsgBox "About to execute query name: " & rs!Name '(for testing. Comment out when live)

    But this doesn't show the prompt box for the update queries. by deleting this line i just don't see the message "About to execute query name...."

    any other idea or I am doing it wrong?

    thanks,

    If you want to see the name of the query that is executing, below is a modification that uses the Status Bar to display the query name and doesn't require a response (like the message box) to continue to the next query.


    Code:
    Sub runQueries()
       Dim db As DAO.Database
       Dim rs As DAO.Recordset
       Dim strSQL As String
       Dim bStatusBar As Variant
    
       Set db = CurrentDb
       strSQL = "SELECT Name FROM MSysObjects WHERE Name Like '0010 01*'"
    
       '(note: if the above syntax doesn't work, you can also create a query using the above, save it as qryMyQueriesToRun, and then...
       '   strSQL = "Select * from qryMyQueriesToRun"
    
    
       'save current status bar state
       bStatusBar = Application.GetOption("Show Status Bar")
    
       ' show status bar
       Application.SetOption "Show Status Bar", True
    
       Set rs = db.OpenRecordset(strSQL)
       If rs.BOF And rs.EOF Then
          rs.Close
          Set rs = Nothing
          MsgBox "No queries to run."
       Else
          rs.MoveLast
          rs.MoveFirst
    
          Do While Not rs.EOF
             ' show which query is executing - see status bar
             Application.SysCmd acSysCmdSetStatus, "Executing query: " & rs!Name
             
             CurrentDb.Execute rs!Name, dbFailOnError
    
             rs.MoveNext
          Loop
       End If
    
       ' clear status bar message
       Application.SysCmd acSysCmdClearStatus
    
       ' set status bar visible state to original state
       If Not bStatusBar Then
          Application.SetOption "Show Status Bar", False
       End If
    
       'clean up and exit
       rs.Close
       Set rs = Nothing
       Set db = Nothing
       MsgBox "Done"
    
    End Sub
    (the added lines are in blue)

  12. #12
    akel210 is offline Novice
    Windows 7 32bit Access 2003
    Join Date
    Feb 2011
    Posts
    4
    you guys are amazing!
    thanks ssanfu problem solved! and thanks to everyone else.

  13. #13
    pkstormy's Avatar
    pkstormy is offline Access/SQL Server Expert
    Windows XP Access 2003
    Join Date
    Mar 2010
    Location
    Madison
    Posts
    682
    Nice code ssanfu. I'll keep that one in my archives. Thanks for the post. I'm not sure if it works in ADO but I tested it with DAO and it worked nicely.

  14. #14
    ssanfu is offline Master of Nothing
    Windows 2K Access 2000
    Join Date
    Sep 2010
    Location
    Anchorage, Alaska, USA
    Posts
    9,664
    Thanks

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

Similar Threads

  1. Running an update query
    By markod in forum Queries
    Replies: 3
    Last Post: 11-11-2010, 01:24 PM
  2. Running sum in queries
    By sankarkunnath in forum Queries
    Replies: 0
    Last Post: 10-24-2010, 12:26 PM
  3. Running update query in access 2010
    By dbansal in forum Queries
    Replies: 1
    Last Post: 09-03-2010, 10:57 AM
  4. Need help with update query / queries
    By Wayne2072 in forum Queries
    Replies: 1
    Last Post: 05-24-2010, 01:42 AM
  5. Help Automatically running and Update Query
    By JohnRandolphSTL in forum Queries
    Replies: 8
    Last Post: 04-13-2010, 02:08 PM

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