Macro to Insert Multiple Columns and Multiple Formulas

TooZippy

Board Regular
Joined
Dec 30, 2018
Messages
70
I am using this macro to insert one column and then to paste a formula in each row of the column. It works except that I want to do it for two columns and two different formulas.

Code:
[LEFT][COLOR=#26282A][FONT=Helvetica Neue]Sub Insert_Col_Form ()[/FONT][/COLOR]
[COLOR=#26282A][FONT=Helvetica Neue]'[/FONT][/COLOR]
[COLOR=#26282A][FONT=Helvetica Neue]'[/FONT][/COLOR]
[COLOR=#26282A][FONT=Helvetica Neue]Dim Rng As Range[/FONT][/COLOR]
[COLOR=#26282A][FONT=Helvetica Neue]    Columns("F:F").Insert[/FONT][/COLOR]
[COLOR=#26282A][FONT=Helvetica Neue]    Set Rng = Range("F2:F" & Range("E2").End(xlDown).Row)[/FONT][/COLOR]
[COLOR=#26282A][FONT=Helvetica Neue]    Rng.FormulaR1C1 = "=IF(LEFT(E2,1)=""-"",MID(E2,2,LEN(E2)),E2)"[/FONT][/COLOR]
[COLOR=#26282A][FONT=Helvetica Neue]    [/FONT][/COLOR]
[COLOR=#26282A][FONT=Helvetica Neue]End Sub[/FONT][/COLOR][/LEFT][B][I][U][SUB][SUP]<strike>
</strike>[/SUP][/SUB][/U][/I][/B][/FONT][/COLOR][COLOR=#222222][FONT=Verdana]

There is another problem with this macro. When it paste the formula in the column, it puts single quotation marks on both sides of the cell references in the formula and the formula does not work due to this insertion. Can those single quotation marks be removed before the macro pastes the formula to the cells? If anybody can help me, I would appreciate it.

Thank you,

Jared Z.
 

Excel Facts

Last used cell?
Press Ctrl+End to move to what Excel thinks is the last used cell.
Remove the R1C1 from the statement

Code:
Sub Insert_Col_Form()
Dim Rng As Range
    Columns("F:F").Insert
    Set Rng = Range("F2:F" & Range("E2").End(xlDown).Row)
    Rng.Formula = "=IF(LEFT(E2,1)=""-"",MID(E2,2,LEN(E2)),E2)"
End Sub
 
Upvote 0
Remove the R1C1 from the statement

Code:
Sub Insert_Col_Form()
Dim Rng As Range
    Columns("F:F").Insert
    Set Rng = Range("F2:F" & Range("E2").End(xlDown).Row)
    Rng.Formula = "=IF(LEFT(E2,1)=""-"",MID(E2,2,LEN(E2)),E2)"
End Sub

Thank you Michael. That should take care of the single quotes being placed around the cell references. I also want to insert two columns with two different formulas. Should I do this..

Code:
[LEFT][COLOR=#222222][FONT=Verdana]Dim Rng As Range[/FONT][/COLOR]
[COLOR=#222222][FONT=Verdana]    Columns("F:F").Insert[/FONT][/COLOR]
[COLOR=#222222][FONT=Verdana]    Set Rng = Range("F2:F" & Range("E2").End(xlDown).Row)[/FONT][/COLOR]
[COLOR=#222222][FONT=Verdana]    Rng.Formula = "=IF(LEFT(E2,1)=""-"",MID(E2,2,LEN(E2)),E2)"[/FONT][/COLOR]
[COLOR=#222222][FONT=Verdana]    Columns("G:G").Insert[/FONT][/COLOR]
[COLOR=#222222][FONT=Verdana]    Set Rng = Range("G2:G" & Range("F2").End(xlDown).Row)[/FONT][/COLOR]
[COLOR=#222222][FONT=Verdana]    Rng.Formula = "=IF(OR(E2=0,E2>0),H2""?"")"[/FONT][/COLOR]
[COLOR=#222222][FONT=Verdana]End Sub[/FONT][/COLOR][/LEFT]

Thank you,

Jared Z
 
Upvote 0
OR, simply
Code:
Sub MM1()
Columns("F:G").Insert
Range("F2:F" & Range("E2").End(xlDown).Row).Formula = "=IF(LEFT(E2,1)=""-"",MID(E2,2,LEN(E2)),E2)"
Range("G2:G" & Range("F2").End(xlDown).Row).Formula = "=IF(OR(E2=0,E2>0),H2,""?"")"
End Sub
 
Upvote 0
OR, simply
Code:
Sub MM1()
Columns("F:G").Insert
Range("F2:F" & Range("E2").End(xlDown).Row).Formula = "=IF(LEFT(E2,1)=""-"",MID(E2,2,LEN(E2)),E2)"
Range("G2:G" & Range("F2").End(xlDown).Row).Formula = "=IF(OR(E2=0,E2>0),H2,""?"")"
End Sub

Thank you MIchael. I will give it a try. It looks like it should work. Thanks again.

Jared Z.
 
Upvote 0

Forum statistics

Threads
1,223,894
Messages
6,175,252
Members
452,623
Latest member
Techenthusiast

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