how to find #ref! invalid cell references within cell formula

B

Brotherharry

I have a formula in a spreadie used by a variety of people that
occasionally becomes corrupted due to cells being deleted improperly
and the cell references being replaced by #ref!.
The formula still generates a valid result, but it's the wrong one
because it's not looking at the correct data because of the corrupted
references.
e.g.
=IF((ISNUMBER(#REF!)),#REF!,(IF((R3134=0),N3134,N3134/R3134)))

This means that what superficially appears to be a functioning
spreadie actually has flaws as the formulas aren't generating correct
results. What I need is a quick way to spot formulas that contain
#REF.

The FIND function won't work as presumably it's only looking in the
result of a formula, not the actual formula itself.
 
B

Brotherharry

hmm, if I use the worksheet Ctrl+F find dialog, I can search for #REF!
which will pick it up, but the issue is I don't know that I need to do
it if the formulas are otherwise producing numeric results
 
S

Stefi

Edit>Find>Enter #REF! in the Find what field>Options>Look in: Select
Values!>Click Find All!

Regards,
Stefi



„Brotherharry†ezt írta:
 
L

Luke M

I believe you meant "Look in: formulas", as the value of OP's formula will
not be the error.
 
B

Brotherharry

It's a solution, but doesn't solve my problem that you have to 'know'
there's a problem that you need to do a Ctrl+F find. If the values
look normal, then a user won't 'know' they need to do the search. I'm
currently using the ISERROR function to pick out that formulas that do
break.

What I need is a way to incorporate the Ctrl+F method into a formula
that sits in the spreadsheet. Once it's generating a value, I can then
use the output to custom format or take some other action to alert the
user that there is an issue.
e.g. stick my magic formula in the last column of a row. get it to
look at all the cells in it's row for #REF! instances. If it finds one
it returns "problem" into the cell it's in. I can then custom format
the whole row to check if that cell contains "problem" and shade all
the cells red.....
eg. =IF((checkforbadrefs(A1:Z1)=TRUE),"problem","no bad refs found")
 
S

Stefi

I was also surprised but #REF! error value was found in VALUES and NOT in
formulas. But if you think it over, it's logical: the formula doesn't CONTAIN
the error value, it just returns it.

Stefi


„Luke M†ezt írta:
 
B

Brotherharry

Found a solution via a vb guru I know.

1. create a custom function in vb to convert all the formulas in a
given range into one long text string

Function ConcatFormulas(InputRange As Range)
' this function works to get all the formulas in a specified range,
' then concatenate their text together into one string
' you can then use the FIND function on the string to check for
problems.
Dim i As Integer
For i = 1 To InputRange.Cells.Count
ConcatFormulas = ConcatFormulas & InputRange(i).Formula
Next i
End Function


2. you can then call the function in the spreadsheet e.g.
=ConcatFormulas(A1:Z21)

3. run a find on the result to look for #REF!
=IF((ISERROR(FIND("#REF!",ConcatFormulas(A1:Z1)))),"ok","doh!")
The above basically says, merge all the formulas into one string, then
try and find the characters #REF!. if excel can't find an instance of
#REF!, everything is Ok.
 

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