Display Cell Addressed by another cell

alc2006

New Member
Joined
Mar 21, 2006
Messages
48
Hello,

I would like to display the cell address that has been addressed by a simple formula in another cell.

i.e. In cell i24 I have the formula =b7
in the adjacent cell, H24, I would like to display "B7", so when I cut and paste both cells, this updates along with the change - is there a formula which can dynamically display this, as opposed to me manually inputting the cell reference, every time I change location?

This is to automatically label ports in pneumatic control system simulations in excel where the output of one device port enters the input port of another device.
ie in pneumatics port 2 (B7) of a 5 port pilot/pilot operated valve extends a piston, so the piston port input formula is =B7, I would like to display this address adjacent to the diagram of the piston.

Thanks,
Annette
 

Excel Facts

What is the fastest way to copy a formula?
If A2:A50000 contain data. Enter a formula in B2. Select B2. Double-click the Fill Handle and Excel will shoot the formula down to B50000.
Try this: press ALT + F11 to open the Visual Basic Editor, Insert > Module and paste in

Code:
Function fmla(r As Range) As String
Application.Volatile
fmla = Right(r.Formula, Len(r.Formula) - 1)
End Function

Press ALT + F11 to return to your sheet. In H24 enter

=fmla(I24)
 
Upvote 0
Hi VoG,

Thanks so much, I have tested it and it works perfectly. I've never used VBA before, I shall pursue this so that I can remove the $ symbol in the display of a fixed reference.

Much appreciated,
Annette
 
Upvote 0
I shall pursue this so that I can remove the $ symbol in the display of a fixed reference.

Hi.

This isn't completely robust but if you are just dealing with simple formulas try

Code:
Function fmla(r As Range) As String
Application.Volatile
fmla = Replace(Right(r.Formula, Len(r.Formula) - 1), "$", "")
End Function
 
Upvote 0
Hi VoG,

Unfortunately, the replace function is undefined - I am only running excel 97 on this machine - I shall run it on XP now as I'm sure that will work. Stand by...

Thanks so much,

Annette
 
Upvote 0
Hi Annette

This should work on versions of Excel even prior to 97

Code:
Function fmla(r As Range) As String
Application.Volatile
fmla = WorksheetFunction.Substitute(Right(r.Formula, Len(r.Formula) - 1), "$", "")
End Function
 
Upvote 0
Hi VoG,

Whilst you were solving my problem, me and my Dad - who wanted the solution - were upstairs on another machine testing your last response on xp with success! Thanks for supplying the alternative for pre-97 versions, which we'll try sometime soon. But your solution for xp is brilliant, just what he wanted.

Many, many thanks from us,
Annette & Mark
 
Upvote 0
Hi VoG,

Whilst you were solving my problem, me and my Dad - who wanted the solution - were upstairs on another machine testing your last response on xp with success! Thanks for supplying the alternative for pre-97 versions, which we'll try sometime soon. But your solution for xp is brilliant, just what he wanted.

Many, many thanks from us,
Annette & Mark


You are both welcome. And thank you for in the first instance giving a complete description of your problem and your politeness in the follow-ups. So different from the 'post and go' merchants who say that they want a macro to make a profit on the stock exchange (or whatever) then never reply to whatever solutions are offered.

Thanks again :)
 
Upvote 0

Forum statistics

Threads
1,214,614
Messages
6,120,519
Members
448,968
Latest member
Ajax40

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top