ID: Q106390
The information in this article applies to:
In Microsoft Excel versions earlier than 5.0, while worksheet protection is enabled and gridlines are turned off, unlocked cells appear underlined. This underline identifies the cells that you can edit.
Although this feature is not available in Microsoft Excel versions 5.0 and later, you can create a macro that will allow you to simulate this behavior.
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/
The following Visual Basic macro places a bottom border on all unlocked
cells in a worksheet. The macro also removes any bottom border from locked
cells. To create the macro, follow these steps:
1. On the Insert menu, point to Macro, and then click Module.
In Microsoft Excel 97 and Microsoft Excel 98, click the Tools menu,
point to Macro, and then click Visual Basic Editor. On the Insert menu,
click Module.
2. In the module, type the following macro code:
Sub Format_Unlocked_Cells()
'Declare procedure-level variables
Dim x As Range, lastcell As Range
'Prevent screen redraw to speed up the macro
Application.ScreenUpdating = False
'Unprotect the worksheet to allow editing
ActiveSheet.Unprotect ("my_password")
'Set lastcell to point to the last cell on the sheet
Set lastcell = Selection.SpecialCells(xlLastCell)
'Place bottom borders on unlocked cells and remove any bottom
'borders from locked cells
For Each x In Range("A1", lastcell)
With x.Borders(xlBottom)
If x.Locked = False Then
.Weight = xlHairline
.ColorIndex = xlAutomatic
Else
.LineStyle = xlNone
End If
End With
Next x
'Re-apply worksheet protection.
ActiveSheet.Protect ("my_password")
End Sub
NOTE: If you want to format a specific cell range, replace
Range("A1", lastcell) with the range you want to format, for example,
Range("A1:G100").
To use the macro, follow these steps:
1. Activate the worksheet that you want to format.
2. On the Tools menu, click Macro. (In Microsoft Excel 97 and Microsoft
Excel 98, click the Tools menu, point to Macro, and then click Macros.)
3. From the list of macros, select the Format_Unlocked_Cells macro. Click
Run.
"Visual Basic User's Guide," version 5.0, Chapter 5
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: 5.00 5.00a 5.00c 7.00 7.00a XL98 XL97 XL7 XL5
Keywords : kbprg kbdta kbdtacode PgmOthr PgmHowto KbVBA
Version : WINDOWS:5.0,7.0,97; MACINTOSH:5.0,98
Platform : MACINTOSH WINDOWS
Issue type : kbhowto
Last Reviewed: May 17, 1999