Visual Basic Macros That Add or Remove Hidden Apostrophes (124935)



The information in this article applies to:

  • Microsoft Excel 2000
  • Microsoft Excel 97 for Windows
  • Microsoft Excel for Windows 95
  • Microsoft Excel for Windows 5.0

This article was previously published under Q124935

SUMMARY

You can use a Visual Basic for Applications macro to change a formula or a value to text and vice versa. To change a formula or value to text, run a macro that adds a hidden leading apostrophe in front of the formula or value. To restore the formula or value, run a macro that removes the apostrophe.

This article contains a sample macro that changes formulas or values in cells to text by adding hidden apostrophes and a sample macro that reverses this process.

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. In Microsoft Excel, you cannot view the formulas in a worksheet in one area of the worksheet and the results of the formulas in another area. Instead, you must edit the formulas so that they appear in text format. To do this, insert an apostrophe in front of the equal sign of the formula. An efficient way to do this is to use a Visual Basic for Applications procedure.

Note that cells in which apostrophes are the first character are not affected by this procedure.

The following procedure adds an apostrophe in front of text, values, or formulas in the current selection:
   'Appends hidden apostrophe as first character.
   'Works on cells with formulas, text, or values.
   'Excellent for displaying formulas when printing.

   Sub ApostroPut()
       For Each currentcell In Selection
           'Prevents inserting apostrophes in blank cells.
           If currentcell.Formula <> "" Then
               currentcell.Formula = "'" & currentcell.Formula
           End If
       Next
   End Sub
				
The following procedure removes the apostrophe in front of text, values, or formulas in the current selection:
   'Removes hidden apostrophes that are first characters.
   'Works on cells with formulas, text, or values.

   Sub ApostroRemove()
       For Each currentcell In Selection
           If currentcell.HasFormula = False Then
               'Verifies that procedure does not change the
               'cell with the active formula so that it contains
               'only the value.
               currentcell.Formula = currentcell.Value
           End If
       Next
   End Sub
				
NOTE: You can restore a value that you changed to text by copying the number 1, selecting the cells that contain the text you want to restore, and using the Paste Special command on the Edit menu with the multiplication operation.

REFERENCES

For additional information about changing a formula or value to text without using a macro, please see the following article in the Microsoft Knowledge Base:

142895 No Match Errors with Replace and Lead Apostrophe

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

226118OFF2000: Programming Resources for Visual Basic for Applications


Modification Type:MinorLast Reviewed:10/11/2006
Keywords:kbdtacode kbhowto kbProgramming KB124935