How to check whether Connection Refresh was successful












1















In Excel 2016 VBA, I'm refreshing several queries like this:



MyWorkbook.Connections(MyConnectionName).Refresh


After the code is done, and no errors are encountered, I see that the hourglass icons for most of the queries are still spinning for several seconds.



Is it possible to check for success AFTER all the refreshes are completed? I'm concerned that my code isn't going to know if an error happens after the code finishes but before the queries are done refreshing.



BTW I don't want to do a RefreshAll, because some of the queries are dependent on others (uses them as a source). I refresh them in a certain sequence so that dependent queries are refreshed after the queries they are dependent on.



UPDATE:



I see that the Connection objects have a read-only RefreshDate property, which at first glance looked like it could be used to do this check:



MyWorkbook.Connections(MyConnectionName).OLEDBConnection.RefreshDate


HOWEVER, it doesn't seem to be getting set. I get an error trying to check it. If I set a Variant variable to that RefreshDate property, the variable shows as "Empty". The source is a SQL server database.










share|improve this question





























    1















    In Excel 2016 VBA, I'm refreshing several queries like this:



    MyWorkbook.Connections(MyConnectionName).Refresh


    After the code is done, and no errors are encountered, I see that the hourglass icons for most of the queries are still spinning for several seconds.



    Is it possible to check for success AFTER all the refreshes are completed? I'm concerned that my code isn't going to know if an error happens after the code finishes but before the queries are done refreshing.



    BTW I don't want to do a RefreshAll, because some of the queries are dependent on others (uses them as a source). I refresh them in a certain sequence so that dependent queries are refreshed after the queries they are dependent on.



    UPDATE:



    I see that the Connection objects have a read-only RefreshDate property, which at first glance looked like it could be used to do this check:



    MyWorkbook.Connections(MyConnectionName).OLEDBConnection.RefreshDate


    HOWEVER, it doesn't seem to be getting set. I get an error trying to check it. If I set a Variant variable to that RefreshDate property, the variable shows as "Empty". The source is a SQL server database.










    share|improve this question



























      1












      1








      1








      In Excel 2016 VBA, I'm refreshing several queries like this:



      MyWorkbook.Connections(MyConnectionName).Refresh


      After the code is done, and no errors are encountered, I see that the hourglass icons for most of the queries are still spinning for several seconds.



      Is it possible to check for success AFTER all the refreshes are completed? I'm concerned that my code isn't going to know if an error happens after the code finishes but before the queries are done refreshing.



      BTW I don't want to do a RefreshAll, because some of the queries are dependent on others (uses them as a source). I refresh them in a certain sequence so that dependent queries are refreshed after the queries they are dependent on.



      UPDATE:



      I see that the Connection objects have a read-only RefreshDate property, which at first glance looked like it could be used to do this check:



      MyWorkbook.Connections(MyConnectionName).OLEDBConnection.RefreshDate


      HOWEVER, it doesn't seem to be getting set. I get an error trying to check it. If I set a Variant variable to that RefreshDate property, the variable shows as "Empty". The source is a SQL server database.










      share|improve this question
















      In Excel 2016 VBA, I'm refreshing several queries like this:



      MyWorkbook.Connections(MyConnectionName).Refresh


      After the code is done, and no errors are encountered, I see that the hourglass icons for most of the queries are still spinning for several seconds.



      Is it possible to check for success AFTER all the refreshes are completed? I'm concerned that my code isn't going to know if an error happens after the code finishes but before the queries are done refreshing.



      BTW I don't want to do a RefreshAll, because some of the queries are dependent on others (uses them as a source). I refresh them in a certain sequence so that dependent queries are refreshed after the queries they are dependent on.



      UPDATE:



      I see that the Connection objects have a read-only RefreshDate property, which at first glance looked like it could be used to do this check:



      MyWorkbook.Connections(MyConnectionName).OLEDBConnection.RefreshDate


      HOWEVER, it doesn't seem to be getting set. I get an error trying to check it. If I set a Variant variable to that RefreshDate property, the variable shows as "Empty". The source is a SQL server database.







      excel vba excel-vba powerquery






      share|improve this question















      share|improve this question













      share|improve this question




      share|improve this question








      edited Apr 21 '17 at 18:00







      Greg Lovern

















      asked Apr 21 '17 at 17:15









      Greg LovernGreg Lovern

      45421227




      45421227
























          1 Answer
          1






          active

          oldest

          votes


















          6














          The QueryTable object exposes two events: BeforeRefresh and AfterRefresh.



          You need to change your paradigm from procedural/imperative to event-driven.



          Say you have this code in ThisWorkbook (won't work in a standard procedural code module, because WithEvents can only be in a class):



          Option Explicit
          Private WithEvents table As Excel.QueryTable
          Private currentIndex As Long
          Private tables As Variant

          Private Sub table_AfterRefresh(ByVal Success As Boolean)
          Debug.Print table.WorkbookConnection.Name & " refreshed. (success: " & Success & ")"
          currentIndex = currentIndex + 1
          If Success And currentIndex <= UBound(tables) Then
          Set table = tables(currentIndex)
          table.Refresh
          End If
          End Sub

          Public Sub Test()
          tables = Array(Sheet1.ListObjects(1).QueryTable, Sheet2.ListObjects(1).QueryTable)
          currentIndex = 0
          Set table = tables(currentIndex)
          table.Refresh
          End Sub


          The tables variable contains an array of QueryTable objects, ordered in the order you wish to refresh them; the currentIndex variable points to the index in that array, for the QueryTable you want to act upon.



          So when Test runs, we initialize the tables array with the QueryTable objects we want to refresh, in the order we want to refresh them.



          The implicit, event-driven loop begins when table.Refresh is called and the QueryTable fires its AfterRefresh event: then we report success, and update the event-provider table object reference with the next QueryTable in the array (only if the refresh was successful), and call its Refresh method, which will fire AfterRefresh again, until the entire array has been traversed or one of them failed to update.






          share|improve this answer



















          • 1





            Thanks, that works great. I had one query that was connection only, so I had to load it to a table so that it would have a ListObject and therefore a Querytable. That added a little bit of file size but it was a small price to pay for this to work.

            – Greg Lovern
            Apr 25 '17 at 17:23











          Your Answer






          StackExchange.ifUsing("editor", function () {
          StackExchange.using("externalEditor", function () {
          StackExchange.using("snippets", function () {
          StackExchange.snippets.init();
          });
          });
          }, "code-snippets");

          StackExchange.ready(function() {
          var channelOptions = {
          tags: "".split(" "),
          id: "1"
          };
          initTagRenderer("".split(" "), "".split(" "), channelOptions);

          StackExchange.using("externalEditor", function() {
          // Have to fire editor after snippets, if snippets enabled
          if (StackExchange.settings.snippets.snippetsEnabled) {
          StackExchange.using("snippets", function() {
          createEditor();
          });
          }
          else {
          createEditor();
          }
          });

          function createEditor() {
          StackExchange.prepareEditor({
          heartbeatType: 'answer',
          autoActivateHeartbeat: false,
          convertImagesToLinks: true,
          noModals: true,
          showLowRepImageUploadWarning: true,
          reputationToPostImages: 10,
          bindNavPrevention: true,
          postfix: "",
          imageUploader: {
          brandingHtml: "Powered by u003ca class="icon-imgur-white" href="https://imgur.com/"u003eu003c/au003e",
          contentPolicyHtml: "User contributions licensed under u003ca href="https://creativecommons.org/licenses/by-sa/3.0/"u003ecc by-sa 3.0 with attribution requiredu003c/au003e u003ca href="https://stackoverflow.com/legal/content-policy"u003e(content policy)u003c/au003e",
          allowUrls: true
          },
          onDemand: true,
          discardSelector: ".discard-answer"
          ,immediatelyShowMarkdownHelp:true
          });


          }
          });














          draft saved

          draft discarded


















          StackExchange.ready(
          function () {
          StackExchange.openid.initPostLogin('.new-post-login', 'https%3a%2f%2fstackoverflow.com%2fquestions%2f43548543%2fhow-to-check-whether-connection-refresh-was-successful%23new-answer', 'question_page');
          }
          );

          Post as a guest















          Required, but never shown

























          1 Answer
          1






          active

          oldest

          votes








          1 Answer
          1






          active

          oldest

          votes









          active

          oldest

          votes






          active

          oldest

          votes









          6














          The QueryTable object exposes two events: BeforeRefresh and AfterRefresh.



          You need to change your paradigm from procedural/imperative to event-driven.



          Say you have this code in ThisWorkbook (won't work in a standard procedural code module, because WithEvents can only be in a class):



          Option Explicit
          Private WithEvents table As Excel.QueryTable
          Private currentIndex As Long
          Private tables As Variant

          Private Sub table_AfterRefresh(ByVal Success As Boolean)
          Debug.Print table.WorkbookConnection.Name & " refreshed. (success: " & Success & ")"
          currentIndex = currentIndex + 1
          If Success And currentIndex <= UBound(tables) Then
          Set table = tables(currentIndex)
          table.Refresh
          End If
          End Sub

          Public Sub Test()
          tables = Array(Sheet1.ListObjects(1).QueryTable, Sheet2.ListObjects(1).QueryTable)
          currentIndex = 0
          Set table = tables(currentIndex)
          table.Refresh
          End Sub


          The tables variable contains an array of QueryTable objects, ordered in the order you wish to refresh them; the currentIndex variable points to the index in that array, for the QueryTable you want to act upon.



          So when Test runs, we initialize the tables array with the QueryTable objects we want to refresh, in the order we want to refresh them.



          The implicit, event-driven loop begins when table.Refresh is called and the QueryTable fires its AfterRefresh event: then we report success, and update the event-provider table object reference with the next QueryTable in the array (only if the refresh was successful), and call its Refresh method, which will fire AfterRefresh again, until the entire array has been traversed or one of them failed to update.






          share|improve this answer



















          • 1





            Thanks, that works great. I had one query that was connection only, so I had to load it to a table so that it would have a ListObject and therefore a Querytable. That added a little bit of file size but it was a small price to pay for this to work.

            – Greg Lovern
            Apr 25 '17 at 17:23
















          6














          The QueryTable object exposes two events: BeforeRefresh and AfterRefresh.



          You need to change your paradigm from procedural/imperative to event-driven.



          Say you have this code in ThisWorkbook (won't work in a standard procedural code module, because WithEvents can only be in a class):



          Option Explicit
          Private WithEvents table As Excel.QueryTable
          Private currentIndex As Long
          Private tables As Variant

          Private Sub table_AfterRefresh(ByVal Success As Boolean)
          Debug.Print table.WorkbookConnection.Name & " refreshed. (success: " & Success & ")"
          currentIndex = currentIndex + 1
          If Success And currentIndex <= UBound(tables) Then
          Set table = tables(currentIndex)
          table.Refresh
          End If
          End Sub

          Public Sub Test()
          tables = Array(Sheet1.ListObjects(1).QueryTable, Sheet2.ListObjects(1).QueryTable)
          currentIndex = 0
          Set table = tables(currentIndex)
          table.Refresh
          End Sub


          The tables variable contains an array of QueryTable objects, ordered in the order you wish to refresh them; the currentIndex variable points to the index in that array, for the QueryTable you want to act upon.



          So when Test runs, we initialize the tables array with the QueryTable objects we want to refresh, in the order we want to refresh them.



          The implicit, event-driven loop begins when table.Refresh is called and the QueryTable fires its AfterRefresh event: then we report success, and update the event-provider table object reference with the next QueryTable in the array (only if the refresh was successful), and call its Refresh method, which will fire AfterRefresh again, until the entire array has been traversed or one of them failed to update.






          share|improve this answer



















          • 1





            Thanks, that works great. I had one query that was connection only, so I had to load it to a table so that it would have a ListObject and therefore a Querytable. That added a little bit of file size but it was a small price to pay for this to work.

            – Greg Lovern
            Apr 25 '17 at 17:23














          6












          6








          6







          The QueryTable object exposes two events: BeforeRefresh and AfterRefresh.



          You need to change your paradigm from procedural/imperative to event-driven.



          Say you have this code in ThisWorkbook (won't work in a standard procedural code module, because WithEvents can only be in a class):



          Option Explicit
          Private WithEvents table As Excel.QueryTable
          Private currentIndex As Long
          Private tables As Variant

          Private Sub table_AfterRefresh(ByVal Success As Boolean)
          Debug.Print table.WorkbookConnection.Name & " refreshed. (success: " & Success & ")"
          currentIndex = currentIndex + 1
          If Success And currentIndex <= UBound(tables) Then
          Set table = tables(currentIndex)
          table.Refresh
          End If
          End Sub

          Public Sub Test()
          tables = Array(Sheet1.ListObjects(1).QueryTable, Sheet2.ListObjects(1).QueryTable)
          currentIndex = 0
          Set table = tables(currentIndex)
          table.Refresh
          End Sub


          The tables variable contains an array of QueryTable objects, ordered in the order you wish to refresh them; the currentIndex variable points to the index in that array, for the QueryTable you want to act upon.



          So when Test runs, we initialize the tables array with the QueryTable objects we want to refresh, in the order we want to refresh them.



          The implicit, event-driven loop begins when table.Refresh is called and the QueryTable fires its AfterRefresh event: then we report success, and update the event-provider table object reference with the next QueryTable in the array (only if the refresh was successful), and call its Refresh method, which will fire AfterRefresh again, until the entire array has been traversed or one of them failed to update.






          share|improve this answer













          The QueryTable object exposes two events: BeforeRefresh and AfterRefresh.



          You need to change your paradigm from procedural/imperative to event-driven.



          Say you have this code in ThisWorkbook (won't work in a standard procedural code module, because WithEvents can only be in a class):



          Option Explicit
          Private WithEvents table As Excel.QueryTable
          Private currentIndex As Long
          Private tables As Variant

          Private Sub table_AfterRefresh(ByVal Success As Boolean)
          Debug.Print table.WorkbookConnection.Name & " refreshed. (success: " & Success & ")"
          currentIndex = currentIndex + 1
          If Success And currentIndex <= UBound(tables) Then
          Set table = tables(currentIndex)
          table.Refresh
          End If
          End Sub

          Public Sub Test()
          tables = Array(Sheet1.ListObjects(1).QueryTable, Sheet2.ListObjects(1).QueryTable)
          currentIndex = 0
          Set table = tables(currentIndex)
          table.Refresh
          End Sub


          The tables variable contains an array of QueryTable objects, ordered in the order you wish to refresh them; the currentIndex variable points to the index in that array, for the QueryTable you want to act upon.



          So when Test runs, we initialize the tables array with the QueryTable objects we want to refresh, in the order we want to refresh them.



          The implicit, event-driven loop begins when table.Refresh is called and the QueryTable fires its AfterRefresh event: then we report success, and update the event-provider table object reference with the next QueryTable in the array (only if the refresh was successful), and call its Refresh method, which will fire AfterRefresh again, until the entire array has been traversed or one of them failed to update.







          share|improve this answer












          share|improve this answer



          share|improve this answer










          answered Apr 21 '17 at 18:59









          Mathieu GuindonMathieu Guindon

          43.9k767150




          43.9k767150








          • 1





            Thanks, that works great. I had one query that was connection only, so I had to load it to a table so that it would have a ListObject and therefore a Querytable. That added a little bit of file size but it was a small price to pay for this to work.

            – Greg Lovern
            Apr 25 '17 at 17:23














          • 1





            Thanks, that works great. I had one query that was connection only, so I had to load it to a table so that it would have a ListObject and therefore a Querytable. That added a little bit of file size but it was a small price to pay for this to work.

            – Greg Lovern
            Apr 25 '17 at 17:23








          1




          1





          Thanks, that works great. I had one query that was connection only, so I had to load it to a table so that it would have a ListObject and therefore a Querytable. That added a little bit of file size but it was a small price to pay for this to work.

          – Greg Lovern
          Apr 25 '17 at 17:23





          Thanks, that works great. I had one query that was connection only, so I had to load it to a table so that it would have a ListObject and therefore a Querytable. That added a little bit of file size but it was a small price to pay for this to work.

          – Greg Lovern
          Apr 25 '17 at 17:23




















          draft saved

          draft discarded




















































          Thanks for contributing an answer to Stack Overflow!


          • Please be sure to answer the question. Provide details and share your research!

          But avoid



          • Asking for help, clarification, or responding to other answers.

          • Making statements based on opinion; back them up with references or personal experience.


          To learn more, see our tips on writing great answers.




          draft saved


          draft discarded














          StackExchange.ready(
          function () {
          StackExchange.openid.initPostLogin('.new-post-login', 'https%3a%2f%2fstackoverflow.com%2fquestions%2f43548543%2fhow-to-check-whether-connection-refresh-was-successful%23new-answer', 'question_page');
          }
          );

          Post as a guest















          Required, but never shown





















































          Required, but never shown














          Required, but never shown












          Required, but never shown







          Required, but never shown

































          Required, but never shown














          Required, but never shown












          Required, but never shown







          Required, but never shown







          Popular posts from this blog

          Contact image not getting when fetch all contact list from iPhone by CNContact

          count number of partitions of a set with n elements into k subsets

          A CLEAN and SIMPLE way to add appendices to Table of Contents and bookmarks