VBA insert formula with relative cell references

si3po

New Member
Joined
Jan 7, 2019
Messages
45
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?
 

Some videos you may like

Excel Facts

Can you sort left to right?
To sort left-to-right, use the Sort dialog box. Click Options. Choose "Sort left to right"

RoryA

MrExcel MVP, Moderator
Joined
May 2, 2008
Messages
34,692
Office Version
365, 2019, 2016, 2010
Platform
Windows, MacOS
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
 

si3po

New Member
Joined
Jan 7, 2019
Messages
45
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.
 

RoryA

MrExcel MVP, Moderator
Joined
May 2, 2008
Messages
34,692
Office Version
365, 2019, 2016, 2010
Platform
Windows, MacOS
Glad to help. :)
 

Watch MrExcel Video

Forum statistics

Threads
1,089,880
Messages
5,410,935
Members
403,335
Latest member
ddaveryos

This Week's Hot Topics

Top