Please Note: This article is written for users of the following Microsoft Excel versions: 97, 2000, 2002, and 2003. If you are using a later version (Excel 2007 or later), this tip may not work for you. For a version of this tip written specifically for later versions of Excel, click here: Checking for Proper Entry of Array Formulas.
Written by Allen Wyatt (last updated December 28, 2024)
This tip applies to Excel 97, 2000, 2002, and 2003
Jeffrey's company has a number of reports that use an extensive number of CSE (Ctrl+Shift+Enter) array formulas. When someone forgets to hold Ctrl and Shift when pressing Enter, the resulting formulas do not equal the correct answer. Auditing each cell, looking for the { } brackets is both tedious and time consuming. Jeffrey wonders if there is a quick way to find the "missing brackets" or raise an error flag if Ctrl+Shift+Enter is not pressed when it should be?
There is no intrinsic or formulaic method of doing this in Excel. This means that you need to turn to a solution that is based on a macro. Fortunately, VBA offers several different ways you can approach this problem. One approach is to simply use a formula to make sure that each formula within a selection is actually an array formula.
Sub MakeCSE1()
Dim rCell As Range
For Each rCell In Selection
rCell.FormulaArray = rCell.Formula
Next rCell
End Sub
This macro assumes that you'll select the cells to be "converted" before actually running the macro. If you prefer, you could define a range of cells (give the range a name) and then run a similar macro that always does its work on that range.
Sub MakeCSE2()
Dim rng As Range
Dim rCell As Range
Dim rArea As Range
Set rng = Range("CSERange")
For Each rArea In rng.Areas
For Each rCell In rArea.Cells
If rCell.HasArray = False Then
rCell.FormulaArray = rCell.Formula
End If
Next rCell
Next rArea
End Sub
This macro looks for a range named CSERange and then checks every cell in the range. If it doesn't contain an array formula, then the formula is converted to an array formula.
Note the use of the HasArray property to check if a cell contains an array formula. This property can actually be helpful in other ways. For instance, you could create a simple user-defined function, such as this:
Function NoCellArray1(rng As Range) As Boolean
NoCellArray1 = Not rng.HasArray
End Function
This function returns True if the cell being pointed to doesn't contain an array formula. If it does contain one, then False is returned. You could then use this function as the basis for a conditional format. All you need to do is create a format that uses it in this way:
=NoCellArray1(A5)
Since NoCellArray returns True if the cell doesn't contain an array formula, your conditional format could set the color of the cell to red or set some other visible sign that the cell doesn't have the requisite array formula. You could also use the following function to accomplish the same task:
Function NoCellArray2(rng As Range) As Boolean
NoCellArray2 = (Evaluate(rng.FormulaArray) <> rng.Value)
End Function
An entirely different approach is to add something to your formulas that allows them to easily be recognized as array formulas. For instance, you could add the following to the end of any of your array formulas:
+N("{")
This doesn't affect the computation in any way, but can be easily checked to see if it is there. The checking can be done by an event handler, such as the following:
Private Sub Worksheet_SelectionChange(ByVal Target As Range)
If Right(Selection.FormulaArray, 5) = "(""{"")" Then
ActiveCell.Select
Selection.FormulaArray = ActiveCell.Formula
End If
End Sub
Note that the handler checks to see if the formula ends with ("{") and, if it does, forces the formula to be treated as an array formula. The great thing about this approach is that you'll never have to press Ctrl+Shift+Enter on the worksheet again—the event handler takes care of it for you. If, at some point, you want to convert the formula back to a regular (non-array) version, simply modify the formula so it doesn't include +N("{").
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (473) applies to Microsoft Excel 97, 2000, 2002, and 2003. You can find a version of this tip for the ribbon interface of Excel (Excel 2007 and later) here: Checking for Proper Entry of Array Formulas.
Professional Development Guidance! Four world-class developers offer start-to-finish guidance for building powerful, robust, and secure applications with Excel. The authors show how to consistently make the right design decisions and make the most of Excel's powerful features. Check out Professional Excel Development today!
With a long list of items in a worksheet, you may want to determine the last time a particular item appeared in the list. ...
Discover MoreIn a series of values you may need to know the smallest value that isn't a zero. There is no built-in function to do ...
Discover MoreExcel provides a variety of tools that allow you to perform operations on your data based upon the characteristics of ...
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 menu interface (Excel 97, Excel 2000, Excel 2002, or Excel 2003)? This site is for you! If you use a later version of Excel, visit our ExcelTips site focusing on the ribbon interface.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2025 Sharon Parq Associates, Inc.
Comments