Removing Left Text from a Cell with condition VBA

TeckTeck

New Member
Joined
Sep 28, 2023
Messages
15
Office Version
  1. 365
Platform
  1. Windows
  2. MacOS
Hi i would like to remove everything that is on the left side of the cell value with 2 conditons

Condition 1: Start removing the left side of the cell when "P" is found and followed by a number Or
Condition 2: Start removing the left side of the cell when "PO" is found and followed by a number

I have tried this code but it doesnt seem to meet my conditions when more there are more than 1 "P" inside the cell and it also doesnt work when "PO" is inside the cell as shown in Column B row 3 and row 2 respectively. Please advice on how i can modify my code to make it work.

VBA Code:
Sub deleteleft()
 
Dim ws As Worksheet
Dim LR As Long
Dim cell As Range
Dim startPosition As Long
 
Set ws = ThisWorkbook.Sheets("Sheet1")
 
 
LR = ws.Cells(ws.Rows.Count, "B").End(xlUp).Row
 
For Each cell In ws.Range("B2:B" & LR)
   If VarType(cell.Value) = vbString Then
       startPosition = InStr(1, cell.Value, "P", vbTextCompare)

       If startPosition > 0 Then
           If IsNumeric(Mid(cell.Value, startPosition + 1, 1)) Or (Mid(cell.Value, startPosition + 1, 2) = "O" And IsNumeric(Mid(cell.Value, startPosition + 2, 1))) Then
               cell.Value = Mid(cell.Value, startPosition)
           End If
       End If
   End If
Next cell
 
  
End Sub

1697680720829.png

VBA Code:
 
Last edited by a moderator:

Excel Facts

Add Bullets to Range
Select range. Press Ctrl+1. On Number tab, choose Custom. Type Alt+7 then space then @ sign (using 7 on numeric keypad)
When posting vba code in the forum, please use the available code tags. It makes your code much easier to read/debug & copy. My signature block below has more details. I have added the tags for you this time. 😊

Also, please investigate XL2BB for providing sample data to make it easier for helpers by not having to manually type out sample data to test with.

Give this a try with a copy of your workbook. Note that it will not work in your Mac environment, only Windows.

VBA Code:
Sub RemoveLeft()
  Dim RX As Object
  Dim a As Variant
  Dim i As Long
 
  Set RX = CreateObject("VBScript.RegExp")
  RX.Pattern = "(^.*?)(PO?\d.*)"
  With Range("B2", Range("B" & Rows.Count).End(xlUp))
    a = .Value
    For i = 1 To UBound(a)
      a(i, 1) = RX.Replace(a(i, 1), "$2")
    Next i
    .Value = a
  End With
End Sub
 
Upvote 0
Solution
When posting vba code in the forum, please use the available code tags. It makes your code much easier to read/debug & copy. My signature block below has more details. I have added the tags for you this time. 😊

Also, please investigate XL2BB for providing sample data to make it easier for helpers by not having to manually type out sample data to test with.

Give this a try with a copy of your workbook. Note that it will not work in your Mac environment, only Windows.

VBA Code:
Sub RemoveLeft()
  Dim RX As Object
  Dim a As Variant
  Dim i As Long
 
  Set RX = CreateObject("VBScript.RegExp")
  RX.Pattern = "(^.*?)(PO?\d.*)"
  With Range("B2", Range("B" & Rows.Count).End(xlUp))
    a = .Value
    For i = 1 To UBound(a)
      a(i, 1) = RX.Replace(a(i, 1), "$2")
    Next i
    .Value = a
  End With
End Sub
Hi Peter thank you for your code and advice, it work perfectly. I would heed your advice next well ! Thank you so much
 
Upvote 0
You're welcome. Glad it worked for you. Thanks for the follow-up. :)
 
Upvote 0

Forum statistics

Threads
1,215,102
Messages
6,123,097
Members
449,096
Latest member
provoking

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