Loop through data and create formulas

jwburritt

New Member
Joined
May 22, 2019
Messages
49
Office Version
  1. 365
Platform
  1. Windows
Hello: I have the following data. I want col A to equal the value of the first cell to its right, but retain it in a formula. For example the successful result in A2 would be "=B2" not "1". The following code gets the value in col A but it's a value, not a formula. Thank you!

[TABLE="width: 256"]
<tbody>[TR]
[TD="class: xl65, width: 64"]A[/TD]
[TD="class: xl65, width: 64"]B[/TD]
[TD="class: xl65, width: 64"]C[/TD]
[TD="class: xl65, width: 64"]D[/TD]
[/TR]
[TR]
[TD="class: xl65"]1[/TD]
[TD="class: xl65"]1[/TD]
[TD="class: xl65"][/TD]
[TD="class: xl65"][/TD]
[/TR]
[TR]
[TD="class: xl65"]2[/TD]
[TD="class: xl65"][/TD]
[TD="class: xl65"]2[/TD]
[TD="class: xl65"][/TD]
[/TR]
[TR]
[TD="class: xl65"]3[/TD]
[TD="class: xl65"][/TD]
[TD="class: xl65"][/TD]
[TD="class: xl65"]3[/TD]
[/TR]
</tbody>[/TABLE]

Code:
Sub temp()

    Dim i As Long
    For i = 2 To 4
    
        Cells(i, 1).Formula = Cells(i, 1).End(xlToRight).Value


    Next i


End Sub
 
Last edited:

Excel Facts

Whats the difference between CONCAT and CONCATENATE?
The newer CONCAT function can reference a range of cells. =CONCATENATE(A1,A2,A3,A4,A5) becomes =CONCAT(A1:A5)
Are you really just trying to come up with a formula in column A to return the first value to the right?
If so, just use this formula in cell A2 and copy down.
Code:
=MATCH(TRUE,INDEX(B2:D2<>0,),0)
 
Upvote 0
Thanks so much. Hadn't thought of that! But it's part of a much larger sheet. And depending on in which column the data sits, the formula as to change. Here's an example. The data in col B needs to be negative and put in col a in a formula. The rest are simple formulas.

[TABLE="width: 716"]
<tbody>[TR]
[TD]A[/TD]
[TD]B[/TD]
[TD]C[/TD]
[TD]D[/TD]
[/TR]
[TR]
[TD]-1[/TD]
[TD]1[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]2[/TD]
[TD][/TD]
[TD]2[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]3[/TD]
[TD][/TD]
[TD][/TD]
[TD]3[/TD]
[/TR]
</tbody>[/TABLE]
 
Last edited:
Upvote 0
Returning to your original macro. Try this

Code:
Sub temp()
  Dim i As Long
  For i = 2 To 4
    Cells(i, "A").Formula = "=" & Cells(i, 1).End(xlToRight).Address
  Next i
End Sub
 
Upvote 0
Thanks, Dante. Works fine. But, it produces absolute cell references. I need relative because it's going to get thrown into a table with existing data. Possible? I've tried everything and can't make it work. Ugh.
 
Upvote 0
Thanks, Dante. Works fine. But, it produces absolute cell references. I need relative because it's going to get thrown into a table with existing data. Possible? I've tried everything and can't make it work. Ugh.

Try:

Code:
Sub temp()
  Dim i As Long
  For i = 2 To 4
    Cells(i, "A").Formula = "=" & Cells(i, 1).End(xlToRight)[COLOR=#0000ff].Address(0, 0)[/COLOR]
  Next i
End Sub
 
Upvote 0
Hello again: I just discovered that the address of the cell reference above needs to also return a structured table address so when I dump the data into the table, the formulas match. In the target table, the formula address are in this form:

=[@[Header]]

They are replicated down in the format above because of the excel calculated column feature in tables. I'm willing to workaround by changing all the formulas in the target table to plain relative formula references -- which Dante's solution provides -- but just thought I'd see if there's vba code that can give a structured table address.

Thanks again!
 
Upvote 0
Hello again: I just discovered that the address of the cell reference above needs to also return a structured table address so when I dump the data into the table, the formulas match. In the target table, the formula address are in this form:

=[@[Header]]

They are replicated down in the format above because of the excel calculated column feature in tables. I'm willing to workaround by changing all the formulas in the target table to plain relative formula references -- which Dante's solution provides -- but just thought I'd see if there's vba code that can give a structured table address.

Thanks again!


I found this way, maybe it will help you.

Code:
Sub Macro1()
  Dim Obj As Object, t As String, i As Long, col As Long, n As String
  Application.AutoCorrect.AutoFillFormulasInLists = False
  For i = 2 To 4
[COLOR=#0000ff]    Set Obj = Range("A" & i).ListObject[/COLOR]
[COLOR=#0000ff]    If Not Obj Is Nothing Then[/COLOR]
[COLOR=#0000ff]      t = Obj.Name[/COLOR]
[COLOR=#0000ff]      col = Cells(i, 1).End(xlToRight).Column[/COLOR]
[COLOR=#0000ff]      n = ActiveSheet.ListObjects(t).ListColumns(col).Name[/COLOR]
[COLOR=#0000ff]      Cells(i, "A").Formula = "=" & t & "[[#This Row],[" & n & "]]"[/COLOR]
    Else
      Cells(i, "A").Formula = "=" & Cells(i, 1).End(xlToRight).Address(0, 0)
    End If
  Next
  Application.AutoCorrect.AutoFillFormulasInLists = True
End Sub
 
Upvote 0

Forum statistics

Threads
1,224,820
Messages
6,181,160
Members
453,021
Latest member
Justyna P

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