XL97: PasteSpecial Method Activates Target SheetLast reviewed: March 13, 1998Article ID: Q158360 |
The information in this article applies to:
SYMPTOMSIn Microsoft Excel 97, if you run a Visual Basic for Applications macro that uses the PasteSpecial method, you may find that the wrong worksheet becomes activated. This may cause problems if your macro assumes that a particular sheet is still active.
CAUSEThis occurs because, in Microsoft Excel 97, the PasteSpecial method activates the sheet into which you are pasting information (the "target sheet"). In earlier versions of Microsoft Excel, the PasteSpecial method does NOT activate the target sheet. Note that this problem occurs only when information is pasted into a sheet other than that from which it was copied.
WORKAROUNDIf you need your Visual Basic macro to copy information from one sheet, PasteSpecial the information into another sheet, and keep the original sheet active, you will need to add two lines of code to the macro. These lines of code keep track of the original sheet and reactivate it after the PasteSpecial method is complete. For example, if your original macro looks like this:
Sub CopyAndPasteSpecial1() Sheets("Sheet1").Range("A1:B5").Copy Sheets("Sheet2").Range("A1").PasteSpecial xlValues End SubYou will need to add two lines to the macro:
Sub CopyAndPasteSpecial2() 'This new line remembers the name of the original sheet. Set xOriginalSheet = ActiveSheet Sheets("Sheet1").Range("A1:B5").Copy Sheets("Sheet2").Range("A1").PasteSpecial xlValues 'This new line activates the original sheet. xOriginalSheet.Activate End SubThe modified code will work in all versions of Microsoft Excel, including Microsoft Excel 97. Microsoft provides examples of Visual Basic for Applications procedures 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. The Visual Basic procedures in this article are provided 'as is' and Microsoft does not guarantee that they can be used in all situations. While Microsoft support engineers can help explain the functionality of a particular macro, they will not modify these examples to provide added functionality, nor will they help you construct macros to meet your specific needs. If you have limited programming experience, you may want to consult one of the Microsoft Solution Providers. Solution Providers offer a wide range of fee-based services, including creating custom macros. For more information about Microsoft Solution Providers, call Microsoft Customer Information Service at (800) 426-9400.
STATUSThis behavior is by design of Microsoft Excel 97.
MORE INFORMATIONIn Microsoft Excel, you can use the PasteSpecial method in a Visual Basic macro when you want to paste copied information in a certain way. For example, if you copy a range of cells that contains formulas, and then you want to paste just the results of the formulas, you could use a line of code similar to the following:
Range("A1").PasteSpecial xlValuesYou can even paste information into a different sheet or into a sheet in another workbook, by adding a reference to the sheet and/or workbook to the line of code. For example:
Workbooks("Book2").Sheets("Sheet3").Range("A1").PasteSpecial xlValuesIf you do this in Microsoft Excel 97, the target sheet (in this case, [Book2]Sheet3) will be activated. This may cause problems if your macro assumes that the original sheet is still active. If this change in behavior causes problems, use the information in the Workaround section to force your macro to reactivate the original sheet.
|
Additional query words: 8.00 97 XL97
© 1998 Microsoft Corporation. All rights reserved. Terms of Use. |