Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. If you are using an earlier version (Excel 2003 or earlier), this tip may not work for you. For a version of this tip written specifically for earlier versions of Excel, click here: Diagonal Borders in a Conditional Format.
Written by Allen Wyatt (last updated August 21, 2021)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365
Parin likes using the diagonal border on some cells to show the value as "crossed out." She would like to use diagonal borders in a conditional format, however. When she tries, she can set other types of borders, but not a diagonal border—it is not selectable in the conditional format. She wonders if there is a way to use diagonal borders with conditional formats.
There is no direct way to do this when setting up a conditional format—Excel simply won't allow you to use diagonal borders with a conditional format. That means that you may want to look for and use an acceptable workaround. Here are a few ideas for the conditional format:
If you actually want to use the diagonal borders, then the only way to do it is to apply an explicit format to the cell and not rely on a conditional format. This can be done through the use of a macro, such as the following:
Private Sub Worksheet_Change(ByVal Target As Range) Dim c As Variant Dim addr As String Set Target = Range("C12:C20") If Intersect(Target, ActiveCell) Is Nothing Then Exit Sub For Each c In Target If c = 0 And Len(c) <> 0 Then addr = c.Address With Range(addr).Borders(xlDiagonalUp) .LineStyle = xlContinuous End With ElseIf c > 0 And Len(c) > 0 Then addr = ActiveCell.Address With Range(addr).Borders(xlDiagonalUp) .LineStyle = xlNone End With End If Next End Sub
You should right-click on a worksheet tab, display the code window from the resulting Context menu, and then paste this macro into the code window. The macro is executed any time a cell is changed in the worksheet. It checks the cells in C12:C20, and if any of them contain a zero value, then the diagonal border is set for that cell.
You can easily change the macro to apply to a different range of cells or to check for a different condition when applying the borders. If you prefer, you can change the xlDiagonalUp constant to xlDiagonalDown, depending on which diagonal border you want applied.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (10693) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. You can find a version of this tip for the older menu interface of Excel here: Diagonal Borders in a Conditional Format.
Excel Smarts for Beginners! Featuring the friendly and trusted For Dummies style, this popular guide shows beginners how to get up and running with Excel while also helping more experienced users get comfortable with the newest features. Check out Excel 2013 For Dummies today!
When you apply conditional formatting, you are not limited to using a single condition. Indeed, you can set up multiple ...
Discover MoreIf you have conditional formatting applied in a worksheet, the formulas in those formats may not be as secure as you ...
Discover MoreThe conditional formatting capabilities of Excel are very helpful when you want to call attention to different values ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)
Got a version of Excel that uses the ribbon interface (Excel 2007 or later)? This site is for you! If you use an earlier version of Excel, visit our ExcelTips site focusing on the menu interface.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2024 Sharon Parq Associates, Inc.
Comments