VBA insert formula with relative cell references

si3po

Board Regular
Joined
Jan 7, 2019
Messages
98
Office Version
  1. 365
  2. 2019
Platform
  1. Windows
hey all, i have the follwing VBA that i'e written, but i think i've messed it up...

Code:
Sub Insert_formula6()
    
    Dim Cell As Range
    Dim InputValue As String
    
    On Error Resume Next
    
    ActiveWorkbook.Sheet2.Activate
    
    lastRow = Sheet2.Range("A" & Rows.Count).End(xlUp).Row
     
    inputformula6 = "=IF((ISERROR(MATCH(V9,'DEMPROG IMPORT'!$AA$9:$AA$5000,0))),""satis"",""live"")"
    Range("w9:w" & lastRow).Select
    For Each Cell In Selection
    If IsEmpty(Cell) Then
    Cell.Value = inputformula6
    End If
    Next
End Sub

the problem being if an empty cell is found, it is populated with the exact formual as in the code. It is suppose to enter the formula with the relative cell reference for that row - e.g. if pasting the formula in my code above into cell W501 it should be populated with the following:

Code:
=IF((ISERROR(MATCH(V501,'DEMPROG IMPORT'!$AA$9:$AA$5000,0))),""satis"",""live"")

could anyone please help convert it to the correct format?
 

Excel Facts

What is =ROMAN(40) in Excel?
The Roman numeral for 40 is XL. Bill "MrExcel" Jelen's 40th book was called MrExcel XL.
You don't really need a loop:

Code:
    On Error Resume Next
    Sheet2.Range("w9:w" & lastRow).SpecialCells(xlCellTypeBlanks).FormulaR1C1 = "=IF((ISERROR(MATCH(RC[-1],'DEMPROG IMPORT'!R9C27:R5000C27,0))),""satis"",""live"")"
   On Error GoTo 0
 
Upvote 0
You don't really need a loop:

Code:
    On Error Resume Next
    Sheet2.Range("w9:w" & lastRow).SpecialCells(xlCellTypeBlanks).FormulaR1C1 = "=IF((ISERROR(MATCH(RC[-1],'DEMPROG IMPORT'!R9C27:R5000C27,0))),""satis"",""live"")"
   On Error GoTo 0

amazing, thank you Rory!

I had a fair few other formulae to convert, but found that the Macro Recorder would convert them all as i typed them in to the R1C1 format for me.
 
Upvote 0

Forum statistics

Threads
1,223,761
Messages
6,174,343
Members
452,556
Latest member
Chrisolowolafe

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