Microsoft KB Archive/191176

From BetaArchive Wiki
Knowledge Base


Article ID: 191176

Article Last Modified on 9/12/2006



APPLIES TO

  • Microsoft Excel 98 for Macintosh



This article was previously published under Q191176


SYMPTOMS

When you use a For Each loop in a Visual Basic for Applications macro, the macro may run without error, but values changed in the For Each loop may not actually change.

CAUSE

Values changed in a For Each loop may only appear to be changed during the running of the macro if the following conditions are true:

  • You are changing the default value property of an object or an element in an array. -and-


  • The loop control variable is a Variant data type.

This behavior is by design of Microsoft Excel.

WORKAROUND

To work around this problem, use either of the following methods:

  • Use the Dim statement to declare the control variable of type Object rather than a Variant data type. -or-


  • Use an explicit default value property in your macro code.


MORE INFORMATION

Microsoft provides programming examples for illustration only, without warranty either expressed or implied. This includes, but is not limited to, the implied warranties of merchantability or fitness for a particular purpose. This article assumes that you are familiar with the programming language that is being demonstrated and with the tools that are used to create and to debug procedures. Microsoft support engineers can help explain the functionality of a particular procedure, but they will not modify these examples to provide added functionality or construct procedures to meet your specific requirements. To demonstrate the issue described earlier, follow these steps:

  1. Save and close all open workbooks and then open a new workbook.
  2. Enter the following in Sheet1:

    A1: 1
    A2: 2
    A3: 3

  3. Start the Visual Basic Editor (press OPTION+F11).
  4. On the Insert menu, click Module.
  5. Enter the following code in the module:

           ' In this macro, cellRange is an Object variable
          ' and cellItem is a Variant variable.
    
          Sub LoopTest()
    
             Set cellRange = ActiveSheet.Range("A1:A3")
    
             ' The following concatenates an "A" to the default value of each
             ' cell.
             For Each cellItem In cellRange
                cellItem = cellItem & "A"
                MsgBox cellItem
             Next
    
             ' The cellRange will return the default value (not value&"A"),
             ' even though the loop above changed the value of the object.
             For Each cellItem In cellRange
                MsgBox cellItem
             Next
    
          End Sub
                            
  6. Run the LoopTest macro.

    The first three message boxes display the values in A1:A3 concatenated with the letter A. However, the next three message boxes display the original values in A1:A3, and when the macro is finished, the values in A1:A3 are unchanged.
  7. Add the following line to the macro just below the Sub LoopTest() line:

          Dim cellItem As Object
                            
  8. Rerun the LoopTest macro.

    The first and second set of message boxes display the values in A1:A3 concatenated with the letter A. When the macro is finished, the values in A1:A3 are also changed accordingly.

NOTE: To work around this issue, you can also change the line of code

   cellItem = cellItem & "A"
                

to:


   
cellItem.Value = cellItem & "A"
                

REFERENCES

For more information about the For Each loop, from the Visual Basic Editor, click the Office Assistant, type for each, click Search, and then click to view "For Each...Next Statement."

NOTE: If the Assistant is hidden, click the Office Assistant button on the Standard toolbar. If the Assistant is not able to answer your query, please see the following article in the Microsoft Knowledge Base:

176476 OFF: Office Assistant Not Answering Visual Basic Questions


For additional information about getting help with Visual Basic for Applications, please see the following article in the Microsoft Knowledge Base:

163435 VBA: Programming Resources for Visual Basic for Applications



Additional query words: XL98

Keywords: kbprb kbdtacode KB191176