#REF error!

T

Tom

Excel 2007 SP2+

I'm getting a #REF error on this:
=IF(D$1+1<=ROW(),SUM(INDIRECT("RawData!F" & ROW()-D$1+1&":RawData!F" &
ROW())),"")

I've tried several ideas... none of them work to resolve the #REF errors.
SOME ideas I've tried: Format to be General, Format to be Number (0 decimal
places), Format to be Text for the D$1 cell. The format on the RawData!
cells are numeric.
In stepping through the calculations, everything appears to work fine except
for the final calculation on
"IF(TRUE,SUM(INDIRECT("RawData!F2:RawData!F5")),"). Once THIS calculation is
performed I receive the #REF error message. I receive
IF(TRUE,(SUM(#REF!),""). So, the issue is evidently relating to the RawData
cells and/or the format of the cell types or ????.
Thanks!

ANY assistance would be appreciated. The format for the cells to store the
SUM calculated values are numeric.
I'm totally lost! ;-(
 
L

Lars-Åke Aspelin

=IF(D$1+1<=ROW(),SUM(INDIRECT("RawData!F" & ROW()-D$1+1&":RawData!F" &
ROW())),"")


Try to remove the second "RawData!", like this:

=IF(D$1+1<=ROW(),SUM(INDIRECT("RawData!F" & ROW()-D$1+1&":F" &
ROW())),"")

Hope this helps / Lars-Åke
 
B

Bernard Liengme

1) now need for sheet refernce twice:
=SUM(INDIRECT("RawData!F" & ROW()-D$1+1&":F" &ROW()))
2) if D1 has value 4, this formula will give REF error in any row less than
4 since the expression Row()-4+1 will evaluate to a negative number in rows
prior to 4
best wishes
 
B

barry houdini

and unless you have a good reason to use INDIRECT then it might b
better to use OFFSET or INDEX, i.e.

=IF(D$1<ROW(),SUM(OFFSET(rawdata!F$1,ROW()-D$1,,D$1)),""
 
T

Tom

Thanks for pointing this out!
Much appreciation!

Bernard Liengme said:
1) now need for sheet refernce twice:
=SUM(INDIRECT("RawData!F" & ROW()-D$1+1&":F" &ROW()))
2) if D1 has value 4, this formula will give REF error in any row less than
4 since the expression Row()-4+1 will evaluate to a negative number in rows
prior to 4
best wishes
 
T

Tom

Barry, thanks...
Now when do I use INDIRECT vs OFFSET vs INDEX then?
How'd you learn these?
 
B

Bernard Liengme

Tom,
Here is an example of where INDIRECT could not be replaced by OFFSET:
Let A1:A10 hold a list of sheet names, and we want to pick values from D10
on each sheet
We could use =INDIRECT(A1&"!D10") or to be more careful (sheet names could
have spaces in them and need to be enclosed in single quotes)
=INDIRECT("'"&A1&"'!D10")
Either formula could eb copried down the column
best wishes
 
T

T. Valko

Just to add my 2 cents....
=IF(D$1<ROW(),SUM(OFFSET(rawdata!F$1,ROW()-D$1,,D$1)),"")

The whole of the formula is based on what row the formula is entered on. If
the OP doesn't provide that info then it's pretty hard to pinpoint the
problem but a #REF! error would usually mean OFFSET is not using a valid
reference.

In general I don't like using ROW() or COLUMN() with no argument. It's safer
to use ROWS(...) and COLUMNS(...).
 

Ask a Question

Want to reply to this thread or ask your own question?

You'll need to choose a username for the site, which only take a couple of moments. After that, you can post your question and our members will help you out.

Ask a Question

Top