Insert row above if cell in column B partially contains 2 (e.g. A2,B2,C2...)

VictoriaExcel

New Member
Joined
Nov 15, 2018
Messages
14
I need a macro that inserts a row above each cell in column B that partially contains 2 e.g. A2, B2, C2 - W2.

Many thanks in advance!
 

Excel Facts

How to show all formulas in Excel?
Press Ctrl+` to show all formulas. Press it again to toggle back to numbers. The grave accent is often under the tilde on US keyboards.
Hi there. This code will do it:
Code:
Sub Macro1()
'
' Macro1 Macro
'

'
With ActiveSheet
    lastrow = .Cells(.Rows.Count, "B").End(xlUp).Row
    For rownum = lastrow To 1 Step -1
    If InStr(.Range("B" & Format(rownum)).Text, "2") > 0 Then
        .Rows(rownum).Insert Shift:=xlDown, CopyOrigin:=xlFormatFromLeftOrAbove
    End If
    Next rownum
End With
End Sub
 
Upvote 0
Hello,

Thank you for your help with this! The macro almost works but unfortunately it inserts rows above A12, B12, C12 etc as well as the intended A2, B2, C2.

Can it work around this with an exception?

Many thanks,

Victoria
 
Upvote 0
Hi Victoria

OK, so if I understand it, you only want blanks above rows in column B which only contain 2 - so A12, C21, D22 etc would not want a blank row. If thats the case, try this:
Code:
Function GetNumeric(CellRef As String)
Dim StringLength As Integer
StringLength = Len(CellRef)
For i = 1 To StringLength
If IsNumeric(Mid(CellRef, i, 1)) Then Result = Result & Mid(CellRef, i, 1)
Next i
GetNumeric = Result
End Function
Sub Macro1()
'
' Macro1 Macro
'

'
With ActiveSheet
    lastrow = .Cells(.Rows.Count, "B").End(xlUp).Row
    For rownum = lastrow To 1 Step -1
    If GetNumeric(.Range("B" & rownum).Text) = 2 Then
        .Rows(rownum).Insert Shift:=xlDown, CopyOrigin:=xlFormatFromLeftOrAbove
    End If
    Next rownum
End With
End Sub

I must admit to lifting the getnumeric code from another forum post - what it does is extract digits only from the entire cell. Hope this helps.

John
 
Last edited:
Upvote 0

Forum statistics

Threads
1,223,904
Messages
6,175,295
Members
452,632
Latest member
jladair

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