The first priority here is to be able to convert a working XL formula into a
form that can be parsed.
This is easily accomplished by incorporating an old XL 4.0 macro into a
*relative* named formula.
We'll configure this named formula to reference the column just to the left
of any cell containing this formula, though it can be configured to work on
*any* cell that's relative to the location of the formula containing cell.
Click in B1.
Doesn't matter if it's empty or populated.
From the Menu Bar:
<Insert. <Name> <Define>
In the "Names In Workbook" box, enter a short name for this formula,
let's use
ext
to denote extract.
Then, change whatever's in the "Refers To" box to:
=Get.Cell(6,A1)
Then <OK>
With a *relative* reference to A1 (no $ signs), and since you clicked in B1
at the start, this formula will work on any cell to the immediate left of
*any* cell that contains this formula.
So, say in D5 you entered:
Cat123
In E5 enter
=ext
and you'll get "cat123" returned.
Now, in D2 enter the formula:
=C2-1234.5
and in E2 enter:
=ext
And you'll get the formula returned, *not* the results of the formula.
Now, to use a Text formula to parse the formula itself.
If all the formulas that you're *ever* going to parse,
will simply have a single negative (=C2-1234.5), or a double negative
(=C2-1234.5-789.5),
then you can just use Rick's formula in the column to the right of the
column containing your formulas:
=LEFT(MID(ext,FIND("-",ext)+1,99),FIND("-",MID(ext,FIND("-",ext)+1,99)&"-")-1)
I got carried away a little, trying to put together a Text formula that
would return the *first negative* number,
no matter what else was in the formula.
So, a formula like this:
=C2+144.1-12.3+J6-250.1
would have a return of "12.3".
=IF(ISERR(FIND("-",ext)),"",LOOKUP(99^99,--MID(MID(ext,FIND("-",ext)+1,10),
MIN(FIND({0,1,2,3,4,5,6,7,8,9},MID(ext,FIND("-",ext)+1,10)&"0123456789")),ROW($1:$10))))
It probably could be shorter, but I'm off to the plant now.
If you like this procedure, don't forget that you can configure the named
formula to work on cells in *any* relative position compared to the location
of the formula containing cell.
And a final caveat.
In XL02 and later, there are no restrictions to the use and copying of these
XL 4.0 macro formulas.
In earlier versions, they should *not* be copied between workbooks,
but they can be copied between sheets within the same WB.
Copying between work*books* in earlier versions, prior to XL02, will crash
XL.
--
HTH,
RD
=====================================================
Please keep all correspondence within the Group, so all may benefit!
=====================================================
In both instances, just the first number 1234.5 - no cell reference,
no signs.
Ed