Pass Cell Address into Formula

nalij_bond

New Member
Joined
Jan 27, 2023
Messages
8
Office Version
  1. 2013
Platform
  1. Windows
Thanks all in advance for your time and help.

My Issue: I am trying to define a variable and use that value to append to a formula within a cell

Current Code:
VBA Code:
Sub test3()
'In the PoC Doc Template, use the address function to find the cell reference column in row 10.
'for the term "VHI PMO/GTM". Then in the Sheet 'Key Stakeholders' in cell H6, use the cell
'reference found and append to the formula'

    Dim VHI_Ref
    
    VHI_Ref = "ADDRESS(12,MATCH(""VHI PMO/GTM"",'PoC Doc Template'!R10,0))"

    Sheets("Key Stakeholders").Range("H6").Formula = "='PoC Doc Template'!" & VHI_Ref

End Sub

Expected Result: What I would like to happen is in the 'Key Stakeholders' worksheet, in cell H6 - a formula like "='PoC Doc Template'!L12" is created.

Current Result: As of now, I keep receiving a Debug Error on the Sheets("Key Stakeholders").Range("H6").Formula = "='PoC Doc Template'!" & VHI_Ref line of code.

Any help would be greatly appreciated!
 
Another option, sticking more to native vba methods might be

VBA Code:
Sub Test4()
  Dim VHI_Ref As Range
  
  Set VHI_Ref = Sheets("PoC Doc Template").Rows(10).Find(What:="VHI PMO/GTM", LookIn:=xlValues, LookAt:=xlWhole)
  Sheets("Key Stakeholders").Range("H6").FormulaR1C1 = "='PoC Doc Template'!R12C" & VHI_Ref.Column
End Sub
 
Upvote 0
Solution

Excel Facts

Format cells as time
Select range and press Ctrl+Shift+2 to format cells as time. (Shift 2 is the @ sign).
Thanks. Try making this change

Rich (BB code):
VHI_Ref = "ADDRESS(12,MATCH(""VHI PMO/GTM"",'PoC Doc Template'!R10,0))"
VHI_Ref = Evaluate("ADDRESS(12,MATCH(""VHI PMO/GTM"",'PoC Doc Template'!10:10,0))")

Thank you again for your assistance.

Using the following code,
VBA Code:
Dim VHI_Ref
    
    VHI_Ref = Evaluate("ADDRESS(12,MATCH(""VHI PMO/GTM"",'PoC Doc Template'!10:10,0))")

    Sheets("Key Stakeholders").Range("H6").Formula = "=PoC Doc Template!" & VHI_Ref & """"

I receive the following error
1674881068087.png


When debugging the code the last line continues to be highlighted, but I can see that the VHI_Ref is now referencing the correct cell!
1674881148499.png


So I've tried the following last line variations without success...

Code:
Sheets("Key Stakeholders").Range("H6").Formula = "=PoC Doc Template!" & VHI_Ref
This opens the following dialogue box
1674881348633.png


Code:
    Sheets("Key Stakeholders").Range("H6").Formula = "="PoC Doc Template!" & VHI_Ref"
This gives me
1674881429151.png


Code:
    Sheets("Key Stakeholders").Range("H6").Formula = "=""PoC Doc Template!"" & VHI_Ref"
This puts the below text in H6
1674881544124.png
 
Upvote 0
Another option, sticking more to native vba methods might be

VBA Code:
Sub Test4()
  Dim VHI_Ref As Range
 
  Set VHI_Ref = Sheets("PoC Doc Template").Rows(10).Find(What:="VHI PMO/GTM", LookIn:=xlValues, LookAt:=xlWhole)
  Sheets("Key Stakeholders").Range("H6").FormulaR1C1 = "='PoC Doc Template'!R12C" & VHI_Ref.Column
End Sub

Not all heroes wear capes!!! Thank you sincerely!!!
 
Upvote 0
Glad the last one worked for you. Thanks for the confirmation. :)

Just to be complete, the previous 'Evaluate' code should work too. However, there should be single quotes around the worksheet name in that error line. You had the single quotes in your original code, which was correct. The suggestion to remove them was incorrect. Try this

VBA Code:
Sub test5()
  'In the PoC Doc Template, use the address function to find the cell reference column in row 10.
  'for the term "VHI PMO/GTM". Then in the Sheet 'Key Stakeholders' in cell H6, use the cell
  'reference found and append to the formula'
  
  Dim VHI_Ref
  
  VHI_Ref = Evaluate("ADDRESS(12,MATCH(""VHI PMO/GTM"",'PoC Doc Template'!10:10,0))")

  Sheets("Key Stakeholders").Range("H6").Formula = "='PoC Doc Template'!" & VHI_Ref

End Sub
 
Upvote 0

Forum statistics

Threads
1,214,651
Messages
6,120,744
Members
448,989
Latest member
mariah3

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