ID: Q177834
The information in this article applies to:
In the versions of Microsoft Excel listed at the beginning of this article, public variables may unexpectedly lose their values. As a result, when you run a Microsoft Visual Basic for Applications procedure or macro that uses the public variables, the procedure or macro may not run correctly or may return incorrect results. (See the "More Information" section of this article for a demonstration of this problem.)
This problem may occur when the following conditions are true:
1. On the Tools menu, click Options.
2. Click the Editor tab.
3. Select the Require Variable Declaration check box.
4. Click OK.
-and-
Worksheets("Sheet1").Copy After:=Worksheets(Worksheets.Count)
Or, you moved or copied a worksheet from another workbook into the workbook that contains the public variables.
To prevent this problem from occurring, follow these steps:
1. In the Visual Basic Editor, click Options on the Tools menu.
2. Click the Editor tab.
3. Click to clear the Require Variable Declaration check box.
4. Click OK.
After completing these steps, your public variables should retain their values even when you copy a worksheet.
Microsoft has confirmed this to be a problem in the Microsoft products listed at the beginning of this article.
Microsoft provides programming examples for illustration only, without warranty either expressed or implied, including, but not limited to, the implied warranties of merchantability and/or fitness for a particular purpose. This article assumes that you are familiar with the programming language being demonstrated and the tools used to create and debug procedures. Microsoft Support professionals 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 needs. If you have limited programming experience, you may want to contact the Microsoft fee-based consulting line at (800) 936-5200. For more information about the support options available from Microsoft, please see the following page on the World Wide Web:
http://www.microsoft.com/support/supportnet/refguide/
In Visual Basic for Applications, you can create a public variable by
adding the word "Public" to a variable declaration at the top of a module.
Example:
Public X As Integer
Public Y As String
Sub Test()
' <Your code goes here.>
End Sub
Normally, public variables retain their values until you close the
workbook in which they are contained. However, if the conditions listed in
the "Cause" section of this article are true, the public variables may
unexpectedly lose their values. The following steps demonstrate this
problem.
1. In Microsoft Excel, create a new workbook.
2. On the Tools menu, point to Macro, and then click Visual Basic Editor.
On the Insert menu, click Module.
3. Type the following code into the new module:
Public X As Integer
Public Y As String
Sub CopySheet()
Worksheets("Sheet1").Copy After:=Worksheets(Worksheets.Count)
End Sub
Sub SetVars()
X = 5
Y = "Hello!"
End Sub
Sub ShowVars()
MsgBox X
MsgBox Y
End Sub
4. On the Tools menu, click Options. Click the Editor tab. Select the
Require Variable Declaration check box, and then click OK.
5. On the File menu, click "Close and Return to Microsoft Excel."
6. On the Tools menu, point to Macro, and then click Macros. Select
SetVars, and then click Run.
The variables now contain the values 5 and "Hello!"
7. On the Tools menu, point to Macro, and then click Macros. Select
ShowVars, and then click Run.
Two message boxes appear containing the values 5 and "Hello!"
8. On the Tools menu, point to Macro, and then click Macros. Select
CopySheet, and then click Run.
Or, click Move Or Copy Sheet on the Edit menu. Select the Create A Copy
check box. In the list, click "(move to end)", and then click OK.
The worksheet Sheet1 is copied; the new worksheet, "Sheet1 (2)," appears
at the end of the workbook.
9. On the Tools menu, point to Macro, and then click Macros. Select
ShowVars, and then click Run.
As before, two message boxes appear. However, the first message box
contains the value zero (0), and the second message box is empty. This
occurs because the act of copying the worksheet reinitialized the public
variables.
If you repeat these steps, but leave the Require Variable Declaration
check box cleared in step 4, the public variables will correctly retain
their values.
For additional information about getting help with Visual Basic for Applications, please see the following article in the Microsoft Knowledge Base:
ARTICLE-ID: Q163435
TITLE : VBA: Programming Resources for Visual Basic for
Applications
Additional query words: XL97 XL98 vba vbe
Keywords : kbprg kbdta kbdtacode xlvbainfo KbVBA
Version : WINDOWS:97; MACINTOSH:98
Platform : MACINTOSH WINDOWS
Issue type : kbbug
Last Reviewed: May 17, 1999