Help converting worksheet formula mid and find to VBA

Liz_I3

Well-known Member
Joined
Dec 30, 2002
Messages
647
Office Version
  1. 2016
Platform
  1. Windows
Hi I want to convert this formula to VBA : =IFERROR(MID(A2,FIND("No",A2,1)+3,13),IFERROR(MID(A2,FIND("Number",A2,1)+7,13),""))


this is my sub that is not working

Sub FindPNumber()
Dim LastRow As Long
Dim i As Long

Range("E1").Value = "P Number"

LastRow = Range("A" & Rows.Count).End(xlUp).Row

For i = 2 To LastRow
Cells(i, 5).Formula = "=WorksheetFunction.IfError(WorksheetFunction.Mid(Range(A2), (Application.WorksheetFunction.Find(""No"", Range(A2), 1) + 3), 13), WorksheetFunction.IfError(WorkSheetFunction.Mid(Range(A2), (Application.WorksheetFunction.Find(""Number"", Range(A2), 1) + 7), 13), ""))"

Next

End Sub

Thank you
 

Excel Facts

Excel Wisdom
Using a mouse in Excel is the work equivalent of wearing a lanyard when you first get to college
Cells(i, 5).Formula = "=WorksheetFunction.IfError(WorksheetFunction.Mid(Range(A2), (Application.WorksheetFunction.Find(""No"", Range(A2), 1) + 3), 13), WorksheetFunction.IfError(WorkSheetFunction.Mid(Range(A2), (Application.WorksheetFunction.Find(""Number"", Range(A2), 1) + 7), 13), ""))"
You would NOT use "WorksheetFunction" in this case. You only use that when wanting to use an Excel function to do a calculation in VBA.
But you are not doing that. By using the ".Formula", it means you are pasting this formula back to the Excel sheet.
So you would NOT use "WorksheetFunction" in a formula on an Excel sheet!

If you want to put it in a formula on your sheet, the easiest way to get what that needs to look like is to turn on the Macro Recorder, and record yourself manually entering the code in a cell in your workbook. Then stop the Macro Recorder and view the code you just recorded. This will give you the syntax you need to put in your VBA code.
 
Upvote 0
VBA Code:
Cells(i, 5).FormulaR1C1 = "=IfError(Mid(R" & i & "C1, Find(""No"", R" & i & "C1, 1) + 3, 13), IfError(Mid(R" & i & "C1, Find(""Number"", R" & i & "C1, 1) + 7, 13),""""))"
OR:
VBA Code:
Cells(i, 5).Formula = "=IfError(Mid(A" & i & ", Find(""No"", A" & i & ", 1) + 3, 13), IfError(Mid(A" & i & ", Find(""Number"", A" & i & ", 1) + 7, 13),""""))"
 
Upvote 0
Neither do you need to loop through the range in order to add the formula to a range.

VBA Code:
Sub FindPNumber()
Dim LastRow As Long
Dim i As Long

Range("E1").Value = "P Number"

LastRow = Range("A" & Rows.Count).End(xlUp).Row

Range("E2:E" & LastRow).Formula = "=IFERROR(MID(A2,FIND(""No"",A2,1)+3,13),IFERROR(MID(A2,FIND(""Number"",A2,1)+7,13),""""))"


End Sub

Hope that helps.
 
Upvote 0

Forum statistics

Threads
1,213,538
Messages
6,114,218
Members
448,554
Latest member
Gleisner2

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