Activecell.FormulaR1C1 throws a Runtime Error '1004' in Excel VBA

Amardeep

New Member
Joined
Jan 10, 2013
Messages
4
This formula was written while recording a Macro. Works perfectly fine in a cell , but when trying to run from VBE ,its throwing a runtime error '1004'. Any help appreciated .... Thanks in Advance


Sub Macro7()
'
' Macro7 Macro
'


'
ActiveCell.FormulaR1C1 = _
"=IF(ISNUMBER(SEARCH("".PRE."",RC[-16])),""Preliminaries"",IF(ISNUMBER(SEARCH("".AUT."",RC[-16])),""Authority Approvals"",IF(ISNUMBER(SEARCH(""MMS"",RC[-16])),""Material& MStatementSubmittals"",IF(ISNUMBER(SEARCH(""SDS"",RC[-16])),""Shop Drawing Submittals"",IF(ISNUMBER(SEARCH("".MMA."",RC[-16])),""Materials& MStatement Approvals"",IF(ISNUMBER(SEARCH("".SDA."",RC[-16" & _
"op Drawing Approvals"",IF(ISNUMBER(SEARCH("".BDS."",RC[-16])),""Builders drawings submittals"",IF(ISNUMBER(SEARCH("".CDS."",RC[-16])),""Coordination drawing submittals"",IF(ISNUMBER(SEARCH("".STR."",RC[-16])),""Structural Concreting works"",IF(ISNUMBER(SEARCH("".MET."",RC[-16])),""Metal Works"",IF(ISNUMBER(SEARCH("".MAD."",RC[-16])),""Material Required on Site"",IF(" & _
"ER(SEARCH("".FIN."",RC[-16])),ISNUMBER(SEARCH("".PMA."",RC[-16])),ISNUMBER(SEARCH("".FLC."",RC[-16]))),""Finishes"",IF(ISNUMBER(SEARCH("".DAW."",RC[-16])),""Doors and windows"",IF(ISNUMBER(SEARCH("".LFT."",RC[-16])),""Lift & Elevators"",IF(ISNUMBER(SEARCH("".ELE."",RC[-16])),""Electrical System"",IF(ISNUMBER(SEARCH("".MEP."",RC[-16])),""Plumbing&firefighting"",IF(IS" & _
"ARCH("".F&F."",RC[-16])),""Firefighting"",IF(ISNUMBER(SEARCH("".HAC."",RC[-16])),""HVAC"",IF(ISNUMBER(SEARCH("".WP"",RC[-16])),""Waterproofing"",IF(ISNUMBER(SEARCH("".LPG."",RC[-16])),""LPG"",""""))))))))))))))))))))"
Range("Q3").Select
End Sub
 

Excel Facts

Why are there 1,048,576 rows in Excel?
The Excel team increased the size of the grid in 2007. There are 2^20 rows and 2^14 columns for a total of 17 billion cells.
This formula was written while recording a Macro. Works perfectly fine in a cell , but when trying to run from VBE ,its throwing a runtime error '1004'. Any help appreciated .... Thanks in Advance


Sub Macro7()
'
' Macro7 Macro
'


'
ActiveCell.FormulaR1C1 = _
"=IF(ISNUMBER(SEARCH("".PRE."",RC[-16])),""Preliminaries"",IF(ISNUMBER(SEARCH("".AUT."",RC[-16])),""Authority Approvals"",IF(ISNUMBER(SEARCH(""MMS"",RC[-16])),""Material& MStatementSubmittals"",IF(ISNUMBER(SEARCH(""SDS"",RC[-16])),""Shop Drawing Submittals"",IF(ISNUMBER(SEARCH("".MMA."",RC[-16])),""Materials& MStatement Approvals"",IF(ISNUMBER(SEARCH("".SDA."",RC[-16" & _
"op Drawing Approvals"",IF(ISNUMBER(SEARCH("".BDS."",RC[-16])),""Builders drawings submittals"",IF(ISNUMBER(SEARCH("".CDS."",RC[-16])),""Coordination drawing submittals"",IF(ISNUMBER(SEARCH("".STR."",RC[-16])),""Structural Concreting works"",IF(ISNUMBER(SEARCH("".MET."",RC[-16])),""Metal Works"",IF(ISNUMBER(SEARCH("".MAD."",RC[-16])),""Material Required on Site"",IF(" & _
"ER(SEARCH("".FIN."",RC[-16])),ISNUMBER(SEARCH("".PMA."",RC[-16])),ISNUMBER(SEARCH("".FLC."",RC[-16]))),""Finishes"",IF(ISNUMBER(SEARCH("".DAW."",RC[-16])),""Doors and windows"",IF(ISNUMBER(SEARCH("".LFT."",RC[-16])),""Lift & Elevators"",IF(ISNUMBER(SEARCH("".ELE."",RC[-16])),""Electrical System"",IF(ISNUMBER(SEARCH("".MEP."",RC[-16])),""Plumbing&firefighting"",IF(IS" & _
"ARCH("".F&F."",RC[-16])),""Firefighting"",IF(ISNUMBER(SEARCH("".HAC."",RC[-16])),""HVAC"",IF(ISNUMBER(SEARCH("".WP"",RC[-16])),""Waterproofing"",IF(ISNUMBER(SEARCH("".LPG."",RC[-16])),""LPG"",""""))))))))))))))))))))"
Range("Q3").Select
End Sub

Can you post the formula as it is written in the cell? It appears that the above formula has too many arguments for one of the If statements. If I could see the formula as written in the cell when it is working that would be helpful.
 
Upvote 0
Can you post the formula as it is written in the cell? It appears that the above formula has too many arguments for one of the If statements. If I could see the formula as written in the cell when it is working that would be helpful.
Thanks for the reply smpatty....this is the formula in the cell

=IF(ISNUMBER(SEARCH(".PRE.",A2)),"Preliminaries",IF(ISNUMBER(SEARCH(".AUT.",A2)),"Authority Approvals",IF(ISNUMBER(SEARCH("MMS",A2)),"Material& MStatementSubmittals",IF(ISNUMBER(SEARCH("SDS",A2)),"Shop Drawing Submittals",IF(ISNUMBER(SEARCH(".MMA.",A2)),"Materials& MStatement Approvals",IF(ISNUMBER(SEARCH(".SDA.",A2)),"Shop Drawing Approvals",IF(ISNUMBER(SEARCH(".BDS.",A2)),"Builders drawings submittals",IF(ISNUMBER(SEARCH(".CDS.",A2)),"Coordination drawing submittals",IF(ISNUMBER(SEARCH(".STR.",A2)),"Structural Concreting works",IF(ISNUMBER(SEARCH(".MET.",A2)),"Metal Works",IF(ISNUMBER(SEARCH(".MAD.",A2)),"Material Required on Site",IF(OR(ISNUMBER(SEARCH(".FIN.",A2)),ISNUMBER(SEARCH(".PMA.",A2)),ISNUMBER(SEARCH(".FLC.",A2))),"Finishes",IF(ISNUMBER(SEARCH(".DAW.",A2)),"Doors and windows",IF(ISNUMBER(SEARCH(".LFT.",A2)),"Lift & Elevators",IF(ISNUMBER(SEARCH(".ELE.",A2)),"Electrical System",IF(ISNUMBER(SEARCH(".MEP.",A2)),"Plumbing&firefighting",IF(ISNUMBER(SEARCH(".F&F.",A2)),"Firefighting",IF(ISNUMBER(SEARCH(".HAC.",A2)),"HVAC",IF(ISNUMBER(SEARCH(".WP",A2)),"Waterproofing",IF(ISNUMBER(SEARCH(".LPG.",A2)),"LPG",""))))))))))))))))))))
 
Upvote 0
Does this give the correct result for A2?
 
Upvote 0
Thanks for the reply smpatty....this is the formula in the cell

=IF(ISNUMBER(SEARCH(".PRE.",A2)),"Preliminaries",IF(ISNUMBER(SEARCH(".AUT.",A2)),"Authority Approvals",IF(ISNUMBER(SEARCH("MMS",A2)),"Material& MStatementSubmittals",IF(ISNUMBER(SEARCH("SDS",A2)),"Shop Drawing Submittals",IF(ISNUMBER(SEARCH(".MMA.",A2)),"Materials& MStatement Approvals",IF(ISNUMBER(SEARCH(".SDA.",A2)),"Shop Drawing Approvals",IF(ISNUMBER(SEARCH(".BDS.",A2)),"Builders drawings submittals",IF(ISNUMBER(SEARCH(".CDS.",A2)),"Coordination drawing submittals",IF(ISNUMBER(SEARCH(".STR.",A2)),"Structural Concreting works",IF(ISNUMBER(SEARCH(".MET.",A2)),"Metal Works",IF(ISNUMBER(SEARCH(".MAD.",A2)),"Material Required on Site",IF(OR(ISNUMBER(SEARCH(".FIN.",A2)),ISNUMBER(SEARCH(".PMA.",A2)),ISNUMBER(SEARCH(".FLC.",A2))),"Finishes",IF(ISNUMBER(SEARCH(".DAW.",A2)),"Doors and windows",IF(ISNUMBER(SEARCH(".LFT.",A2)),"Lift & Elevators",IF(ISNUMBER(SEARCH(".ELE.",A2)),"Electrical System",IF(ISNUMBER(SEARCH(".MEP.",A2)),"Plumbing&firefighting",IF(ISNUMBER(SEARCH(".F&F.",A2)),"Firefighting",IF(ISNUMBER(SEARCH(".HAC.",A2)),"HVAC",IF(ISNUMBER(SEARCH(".WP",A2)),"Waterproofing",IF(ISNUMBER(SEARCH(".LPG.",A2)),"LPG",""))))))))))))))))))))

This will work when the activecell is in column Q

Code:
ActiveCell.FormulaR1C1 = "=IF(ISNUMBER(SEARCH("".PRE."",RC[-16])),""Preliminaries"",IF(ISNUMBER(SEARCH("".AUT."",RC[-16])),""Authority Approvals""," & _
"IF(ISNUMBER(SEARCH(""MMS"",RC[-16])),""Material& MStatementSubmittals"",IF(ISNUMBER(SEARCH(""SDS"",RC[-16])),""Shop Drawing Submittals""," & _
"IF(ISNUMBER(SEARCH("".MMA."",RC[-16])),""Materials& MStatement Approvals"",IF(ISNUMBER(SEARCH("".SDA."",RC[-16])),""Shop Drawing Approvals""," & _
"IF(ISNUMBER(SEARCH("".BDS."",RC[-16])),""Builders drawings submittals"",IF(ISNUMBER(SEARCH("".CDS."",RC[-16])),""Coordination drawing submittals""," & _
"IF(ISNUMBER(SEARCH("".STR."",RC[-16])),""Structural Concreting works"",IF(ISNUMBER(SEARCH("".MET."",RC[-16])),""Metal Works""," & _
"IF(ISNUMBER(SEARCH("".MAD."",RC[-16])),""Material Required on Site"",IF(OR(ISNUMBER(SEARCH("".FIN."",RC[-16])),ISNUMBER(SEARCH("".PMA."",RC[-16]))," & _
"ISNUMBER(SEARCH("".FLC."",RC[-16]))),""Finishes"",IF(ISNUMBER(SEARCH("".DAW."",RC[-16])),""Doors and windows"",IF(ISNUMBER(SEARCH("".LFT."",RC[-16]))," & _
"""Lift & Elevators"",IF(ISNUMBER(SEARCH("".ELE."",RC[-16])),""Electrical System"",IF(ISNUMBER(SEARCH("".MEP."",RC[-16])),""Plumbing&firefighting""," & _
"IF(ISNUMBER(SEARCH("".F&F."",RC[-16])),""Firefighting"",IF(ISNUMBER(SEARCH("".HAC."",RC[-16])),""HVAC"",IF(ISNUMBER(SEARCH("".WP"",RC[-16]))," & _
"""Waterproofing"",IF(ISNUMBER(SEARCH("".LPG."",RC[-16])),""LPG"",""""))))))))))))))))))))"
 
Upvote 0
Just realised I never supplied the code in post#4.
Does this give the correct result for A2?
Code:
Sub Macro1()
   Dim ary As Variant
   Dim i As Long
   
   ary = Array(".PRE.", "Preliminaries", ".AUT.", "Authority Approvals", "MMS", "Material& MStatementSubmittals", "SDS", "Shop Drawing Submittals", ".MMA.", "Materials& MStatement Approvals", ".SDA.", "Shop Drawing Approvals", ".BDS.", "Builders drawings submittals", ".CDS.", "Coordination drawing submittals", ".STR.", "Structural Concreting works", ".MET.", "Metal Works", ".MAD.", "Material Required on Site", ".FIN.", "Finishes", ".PMA.", "Finishes", ".FLC.", "Finishes", ".DAW.", "Doors and windows", ".LFT.", "Lift & Elevators", ".ELE.", "Electrical System", ".MEP.", "Plumbing&firefighting", ".F&F.", "Firefighting", ".HAC.", "HVAC", ".WP", "Waterproofing", ".LPG.", "LPG")
   For i = 0 To UBound(ary) Step 2
      If InStr(1, Range("A2").Value, ary(i), vbTextCompare) > 0 Then
         Range("Q2").Value = ary(i + 1)
         Exit For
      End If
   Next i
End Sub
 
Upvote 0

Forum statistics

Threads
1,223,888
Messages
6,175,219
Members
452,620
Latest member
dsubash

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