Error during pasting Excel formula consisting of Mid, Len, Search into VBA module

reubanrao93

New Member
Joined
Dec 7, 2020
Messages
20
Office Version
  1. 365
Platform
  1. Windows
Hi guys, I'm trying to insert a formula in my code which works in the sheet but not in vba. Running the code below returns a syntax error. I noticed that the errors are due to SEARCH strings containing paratheses for "ENO=" and ",SUB". I've tried changing the paratheses to CHR(34) as well but now it returns run-time error 1004 instead. Is there something I'm missing here?

*ORIGINAL*

Sub PastFormula()
Dim LRw As Long
Sheets("Sheet1").Range("S:S").Select
ActiveCell.Formula = "=MID(L2,(LEN(L2)-(LEN(LEFT(L2,LEN(L2)-SEARCH(“ENO=“,L2)))-4)),((LEN(LEFT(L2,LEN(L2)-SEARCH(“ENO=“,L2)))-4)-(LEN(LEFT(L2,LEN(L2)-SEARCH(“,SUB”,L2))))))"
LRw = Range ("L" & Rows.Count).End(xlUp).Row
Range(ActiveCell, Cells(LRw, ActiveCell.Column)).FillDown
End Sub

*Parantheses changed into CHR(34)*

Sub PastFormula()
Dim LRw As Long
Sheets("Sheet1").Range("S:S").Select
ActiveCell.Formula = "=MID(L2,(LEN(L2)-(LEN(LEFT(L2,LEN(L2)-SEARCH(CHR(34)&ENO=&CHR(34),L2)))-4)),((LEN(LEFT(L2,LEN(L2)-SEARCH(CHR(34)&ENO=&CHR(34),L2)))-4)-(LEN(LEFT(L2,LEN(L2)-SEARCH(CHR(34)&,SUB&CHR(34),L2))))))"
LRw = Range("L" & Rows.Count).End(xlUp).Row
Range(ActiveCell, Cells(LRw, ActiveCell.Column)).FillDown
End Sub
 

Excel Facts

Ambidextrous Undo
Undo last command with Ctrl+Z or Alt+Backspace. If you use the Undo icon in the QAT, open the drop-down arrow to undo up to 100 steps.
VBA Code:
Sub PastFormula()
Dim LRw As Long
Sheets(1).Range("S:S").Select
ActiveCell.Formula = "=MID(L2,(LEN(L2)-(LEN(LEFT(L2,LEN(L2)-SEARCH(""ENO="",L2)))-4)),((LEN(LEFT(L2,LEN(L2)-SEARCH(""ENO="",L2)))-4)-(LEN(LEFT(L2,LEN(L2)-SEARCH(""SUB"",L2))))))"
LRw = Range("L" & Rows.Count).End(xlUp).Row
Range(ActiveCell, Cells(LRw, ActiveCell.Column)).FillDown
End Sub
 
Upvote 0
Solution

Forum statistics

Threads
1,216,127
Messages
6,129,024
Members
449,482
Latest member
al mugheen

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