XL97: Problems Using ColorIndex to Set Color of Borders

ID: Q171953

The information in this article applies to:

SYMPTOMS

In Microsoft Excel 97, if you run a Visual Basic for Applications macro that uses the ColorIndex property to specify a color for the borders of a cell, some of the borders may fail to use that color or may not appear. For example, this problem occurs when you use the following sample code in a macro:

   ActiveCell.Borders.ColorIndex = 3

CAUSE

This problem occurs because Microsoft Excel 97 applies the specified color to only the left, right, top, and bottom borders.

WORKAROUND

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 example code uses the ColorIndex property to specify a color for the borders of a cell or a range of cells.

Left, Right, Top, and Bottom Borders

To use the ColorIndex property for these types of borders, set the ColorIndex property to the value you want, for example:

   ActiveCell.Borders(xlEdgeLeft).ColorIndex = 2
   ActiveCell.Borders(xlEdgeRight).ColorIndex = 3
   ActiveCell.Borders(xlEdgeTop).ColorIndex = 4
   ActiveCell.Borders(xlEdgeBottom).ColorIndex = 5

You can set all four borders to the same value by using a line of code similar to the following:

   ActiveCell.Borders.ColorIndex = 6

Inside Vertical and Inside Horizontal Borders

To use the ColorIndex property for these types of borders, set the ColorIndex property for the appropriate constant to the correct value, for example:

   Selection.Borders(xlInsideVertical).ColorIndex = 7
   Selection.Borders(xlInsideHorizontal).ColorIndex = 8

NOTE: When you use the xlInsideVertical constant, the selected range must contain at least two columns. When you use the xlInsideHorizontal constant, the selected range must contain at least two rows. If the selection does not contain the necessary number of columns or rows, you receive the following error message:

   Run-time error '1004':
   Unable to set the ColorIndex property of the Border class

Diagonal Up and Diagonal Down Borders

To use the ColorIndex property for these types of borders, first set the Weight property of the border, for example:

   With Selection.Borders(xlDiagonalUp)
       .Weight = xlThin
       .ColorIndex = 9
   End With

-or-

   Selection.Borders(xlDiagonalDown).Weight = xlMedium
   Selection.Borders(xlDiagonalDown).ColorIndex = 10

NOTE: If you use the ColorIndex property of the diagonal border before you set its Weight property, the ColorIndex property is ignored, and the border appears in the default color (black). If you do not set the Weight property, the border does not appear.

STATUS

This behavior, with the exception of the behavior of diagonal borders, is by design of Microsoft Excel 97.

Microsoft has confirmed the behavior of diagonal borders to be a problem in the Microsoft products listed at the beginning of this article.

MORE INFORMATION

In Microsoft Excel 97, if you run a macro with the following line of code

   MsgBox ActiveCell.Borders.Count

a message box with the number of borders for the active cell appears. By running this macro, you can determine that a cell contains six borders: left, right, top, bottom, diagonal up, and diagonal down. However, if you specify a color for all six borders by running a macro that uses the following line of code

   ActiveCell.Borders.ColorIndex = 3

the color for only the first four borders is changed. The color for the diagonal borders is not changed because no weight is specified for them. Note that you can use the workaround in this article to force the diagonal borders to appear.

Additional query words: XL97

Keywords          : kbprg kbdta kbdtacode OffVBA KbVBA 
Version           : WINDOWS:97
Platform          : WINDOWS
Issue type        : kbbug

Last Reviewed: May 18, 1999