XL97: Cannot Paste Array Formula in Its Original Cell (158080)
The information in this article applies to:
- Microsoft Excel 97 for Windows
This article was previously published under Q158080 SYMPTOMS
When you run a Visual Basic for Applications macro in Microsoft Excel 97,
you may receive the following error message:
Run-time error '1004':
You cannot change part of an array.
Or when you manually paste a copied cell in Microsoft Excel 97, you may
receive the following error message:
You cannot change part of an array.
CAUSE
This will occur if you copy (either manually or through a macro) a cell
that contains an array formula and then attempt to paste the copied formula
into a range of cells that also includes the original cell. For example,
you copy cell A1 and then attempt to paste it to cells A1 through A10.
This behavior is by design of Microsoft Excel.
WORKAROUND
If you manually copy and paste a formula that is part of an array, use the
following steps to copy and paste the formula without receiving an error
message:
- Select the cell that contains the array formula (for example cell A1).
- Press F2, and then press ENTER.
If you receive the error message "You cannot change part of an array"
this array formula is entered into multiple cells. Click OK.
- Select the range of cells, including the original cell, into which
the array formula should be entered (for example A1:A10). Make sure
that the cell that contains the formula is the active cell.
- Press F2, then press CTRL+SHIFT+ENTER.
The array formula is now entered into the entire range of cells.
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 a Microsoft Certified Partner or the Microsoft fee-based
consulting line at (800) 936-5200. For more information about Microsoft Certified
Partners, please visit the following Microsoft Web site:
For more information about the support options that are available and about how to contact Microsoft, visit the following Microsoft Web site:
To prevent this problem from occurring when you copy and paste the formula
with a macro, you should perform the following steps in your macro:
- Read the array formula from the original cell, and store the formula
in a variable.
- Clear the original cell.
- Apply the stored formula to all of the cells in the range, including
the original cell.
The following sample macro demonstrates how to do this. In this example,
cell A1 contains the array formula "=SUM(IF(B1:B100=0,1,0))", (without
quotation marks). The macro applies this formula to the range A1:A10.
Sub CopyArrayFormula()
'stores formula in variable
xFormula = Range("A1").Formula
'clears formula from cell
Range("A1").Clear
'applies formula
Range("A1:A10").FormulaArray = xFormula
End Sub
MORE INFORMATION
In Microsoft Excel, array formulas are a special type of formula that allow
you to perform a large number of calculations in a single cell. When you
want to enter a formula as an array formula, instead of just pressing
ENTER, you press CTRL+SHIFT+ENTER.
In earlier versions of Microsoft Excel, it is possible for you or a Visual
Basic macro to paste a copied array formula in a range of cells that
includes the original copied cell.
In Microsoft Excel 97, this will not work unless you first clear the
original cell, or convert it into a normal formula. This behavior is
actually correct: the behavior of earlier versions of Microsoft Excel is
incorrect.
Modification Type: | Minor | Last Reviewed: | 10/10/2006 |
---|
Keywords: | kberrmsg kbprb kbProgramming kbualink97 KB158080 |
---|
|