VBA: Concatenating Formula with String Variable

AFPathfinder

Well-known Member
Joined
Apr 8, 2012
Messages
531
Office Version
  1. 365
  2. 2016
Platform
  1. Windows
Thanks for taking a look at this thread. I'm getting the generic 1004 error on the Range.FormulaR1C1 line, but I can't seem to see the problem.

Code:
Sub UpdateFormulas()
    Dim stockFund As String
    For i = 2 To finalRow
        If Cells(i, 1).Value = "30455" Then
            Cells(i, 5).Value = "=IF(RC[1]-RC[2]=0,-1,RC[1]-RC[2])"
            stockFund = Cells(i, 5).Address
            Exit For
        End If
    Next i
    Range("E" & finalRow + 1).FormulaR1C1 = "=SUM(R2C:R[-1]C)-" & stockFund
End Sub
The mouse-over on the stockFund variable in that last line shows the correct cell address as the value and I checked the If statement to ensure it actually finds the number. I would guess that it would be a syntax error with that line, but it looks correct to me. Any ideas?
 

Excel Facts

Is there a shortcut key for strikethrough?
Ctrl+S is used for Save. Ctrl+5 is used for Strikethrough. Why Ctrl+5? When you use hashmarks to count |||| is 4, strike through to mean 5.
Have you tried using Val(stockFund) in place of stockFund in the formula?
 
Upvote 0
It doesn't error out, but it enters 0 in the formula. In this scenario, I'm hoping for $E$5 at the end of that formula. Thanks for the info, I've never used Val() before.
 
Upvote 0
Maybe put a "stop" in the code just before the "exit for". When(/If) the code stops, check the value of the variables.

Also, consider what the code will do if it doesn't find "30455". Which I note is (surprisingly, maybe) a string, not a number. The code needs to work whatever happens - finds or doesn't find "30455".

Consider using `range reference`.Find instead of the loop. Usual check is if the range found is not nothing to know whether or not the find has found what you're after or not. Info below copied from Excel VBA help.

regards


Copied from help. It has formatted poorly but I've posted it to help you know where to look. VBA help has the info.
Find method as it applies to the Range object.</STRONG>
Finds specific information in a range, and returns a Range object that represents the first cell where that information is found. Returns Nothing if no match is found. Doesn’t affect the selection or the active cell.
For information about using the Find worksheet function in Visual Basic, see Using Worksheet Functions in Visual Basic.
expression.Find(What, After, LookIn, LookAt, SearchOrder, SearchDirection, MatchCase, MatchByte, SearchFormat)
expression Required. An expression that returns a Range object.
What Required Variant. The data to search for. Can be a string or any Microsoft Excel data type.
After Optional Variant. The cell after which you want the search to begin. This corresponds to the position of the active cell when a search is done from the user interface. Note that After must be a single cell in the range. Remember that the search begins after this cell; the specified cell isn’t searched until the method wraps back around to this cell. If you don’t specify this argument, the search starts after the cell in the upper-left corner of the range.
LookIn Optional Variant. The type of information.
LookAt Optional Variant. Can be one of the following XlLookAt constants: xlWhole or xlPart.
SearchOrder Optional Variant. Can be one of the following XlSearchOrder constants: xlByRows or xlByColumns.
SearchDirection Optional XlSearchDirection
. The search direction.
XlSearchDirection can be one of these XlSearchDirection constants.

<TBODY>
</TBODY>
xlPrevious</STRONG>

<TBODY>
</TBODY>


MatchCase Optional Variant. True to make the search case sensitive. The default value is False.
MatchByte Optional Variant. Used only if you’ve selected or installed double-byte language support. True to have double-byte characters match only double-byte characters. False to have double-byte characters match their single-byte equivalents.
SearchFormat Optional Variant. The search format.
Remarks

The settings for LookIn, LookAt, SearchOrder, and MatchByte are saved each time you use this method. If you don’t specify values for these arguments the next time you call the method, the saved values are used. Setting these arguments changes the settings in the Find dialog box, and changing the settings in the Find dialog box changes the saved values that are used if you omit the arguments. To avoid problems, set these arguments explicitly each time you use this method.
You can use the FindNext</STRONG> and FindPrevious methods to repeat the search.
When the search reaches the end of the specified search range, it wraps around to the beginning of the range. To stop a search when this wraparound occurs, save the address of the first found cell, and then test each successive found-cell address against this saved address.
To find cells that match more complicated patterns, use a For Each...Next statement with the Like operator. For example, the following code searches for all cells in the range A1:C5 that use a font whose name starts with the letters Cour. When Microsoft Excel finds a match, it changes the font to Times New Roman.

<CODE>For Each c In [A1:C5] If c.Font.Name Like "Cour*" Then c.Font.Name = "Times New Roman" End IfNext</CODE>


</PRE>
Example

This example finds all cells in the range A1:A500 on worksheet one that contain the value 2 and changes it to 5.

<CODE>With Worksheets(1).Range("a1:a500") Set c = .Find(2, lookin:=xlValues) If Not c Is Nothing Then firstAddress = c.Address Do c.Value = 5 Set c = .FindNext(c) Loop While Not c Is Nothing And c.Address <> firstAddress End IfEnd With</CODE>


</PRE>
</STRONG></STRONG></STRONG></STRONG></STRONG></STRONG></STRONG></STRONG></STRONG></STRONG></STRONG></STRONG></STRONG></STRONG></STRONG></STRONG></STRONG></STRONG></STRONG></STRONG></STRONG></STRONG></STRONG></STRONG></STRONG></STRONG></STRONG></STRONG></STRONG></STRONG></STRONG></STRONG></STRONG></STRONG></STRONG></STRONG></STRONG></STRONG></STRONG></STRONG></STRONG></STRONG></STRONG></STRONG></STRONG></STRONG></STRONG></STRONG></STRONG></STRONG></STRONG></STRONG></STRONG></STRONG>
 
Upvote 1
Good points. The Dim stockFund As String is for two reasons. The number is actually a document ID and is treated as text in the sheet even though integer would probably still work. I was under the impression that in order to variable the cell address for concatenation it should be a string. I did try Dim As Range at first, but found an example of someone doing something similar with it defined as String.

I've checked at debug from the error and the variable is holding the correct data. I'll try playing around with Range again and see if I can get it working.

I see your point in if the string isn't found and I'll have to work on that. I'm trying to bolster the code and prepare it to share with other work centers, but it's true that they may not have a stock fund to worry about. I was ultimately going to use a variable for the document number in conjunction with some kind of config sheet.
 
Upvote 0
Your comments show a good understanding of what you're doing. I don't want to set you on a wrong path. It is good to be aware of variable types and handle them correctly - and I see that is what you're doing. VBA might coerce values to be what it can handle: if there is any doubt, be explicit so that the code does what you want. For example if you had a numeric 30455 you can force it to be a string with CStr(30455) or if it were string "30455" you can explicitly make it an integer with CInt("30455") or long using CLng("30455")

You wrote "I was under the impression that in order to variable the cell address for concatenation it should be a string." Absolutely correct. My comments about a range object relate to using the find method.

You also wrote "I've checked at debug from the error and the variable is holding the correct data. I'll try playing around with Range again and see if I can get it working." With the right variable result something is amiss. Please post again if you don't sort this out.

Cheers
 
Upvote 1
I've done code like this before without a problem, but this one has got me stumped. I took out the Exit For in the loop and no difference. I added another variable after the loop that equaled the variable in the loop and no change either. I tried Option Explicit and received the same error even though I'm not 100% sure what Option Explicit is. I also tried changing .FormulaR1C1 to .Value and no go.

The variable is only for that formula and used no where else in the code. The error is Run-time 1004 - Application-defined or object-defined. I can post all 147 lines of the code if it would help, but I don't believe the other pieces of code are the culprit. I'll start rereading the variables section of Mr. Jelen's book in the mean time and see if I can pick up on anything.
 
Upvote 0
Thanks for taking a look at this thread. I'm getting the generic 1004 error on the Range.FormulaR1C1 line, but I can't seem to see the problem.

Code:
Sub UpdateFormulas()
    Dim stockFund As String
    For i = 2 To finalRow
        If Cells(i, 1).Value = "30455" Then
            Cells(i, 5).Value = "=IF(RC[1]-RC[2]=0,-1,RC[1]-RC[2])"
            [B][COLOR=#a52a2a]stockFund = Cells(i, 5).[/COLOR][COLOR=#a52a2a]Address[/COLOR][/B]
            Exit For
        End If
    Next i
    Range("E" & finalRow + 1).FormulaR1C1 = "=SUM(R2C:R[-1]C)-" & [COLOR=#000000]stockFund
[/COLOR]End Sub
The mouse-over on the stockFund variable in that last line shows the correct cell address as the value and I checked the If statement to ensure it actually finds the number. I would guess that it would be a syntax error with that line, but it looks correct to me. Any ideas?
I think the problem maybe that stockFund is being returned in A1 notation and you are concatenating it into a formula using R1C1 notation. I haven't tested it, but try changing the line of code I highlighted in red to this...
Rich (BB code):
stockFund = Cells(i, 5).Address(,,xlR1C1)
 
Upvote 0
Solution
Spot on! I didn't even think about that problem. The mouse-over was showing $E$5 and not R5C5. Thank you for the assistance and also for the explanation. I hate making changes without understanding the reasoning.

Thank you for helping me work through this logically as well, Fazza.
 
Upvote 0

Forum statistics

Threads
1,214,522
Messages
6,120,022
Members
448,939
Latest member
Leon Leenders

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