VBA Formulas

G

Guest

Guest
Hi,
Basically I am trying to write a macro that writes formulas based on a list of headers

=COUNTIF('Raw Data'!E2:E46, "F02")

the function so far --

With Range("C22")
.FormulaR1C1 = "F02"
.Offset(0, 1).FormulaR1C1 = "=COUNTIF('Raw Data'!R[2]C[1]:R[46]C[1], ""F02"")"
.Offset(0, 2).FormulaR1C1 = "Array Formula"
End With

The formula was recorded using macro recorder. It's not working as the arguments.. R[2]C[1]:R[46]C[1], produced the formula =COUNTIF('Raw Data'!E42:E65534, "F02") instead of =COUNTIF('Raw Data'!E2:E46, "F02"). Help!
 

Excel Facts

How to find 2nd largest value in a column?
MAX finds the largest value. =LARGE(A:A,2) will find the second largest. =SMALL(A:A,3) will find the third smallest
Hi

The code that you have recorded is relative to the cell it's entered in. If you always want a relative reference to always be the same try:

Dim strAdd As String
strAdd = Range("E2:E46").Address _
(RowAbsolute:=False, columnAbsolute:=False, _
ReferenceStyle:=xlR1C1, RelativeTo:=Range("D22"))

With Range("C22")
.FormulaR1C1 = "F02"
.Offset(0, 1).FormulaR1C1 = "=COUNTIF('Raw Data'!" & strAdd & ", ""F02"")"
.Offset(0, 2).FormulaR1C1 = "Array Formula"
End With
 
Upvote 0

Forum statistics

Threads
1,213,532
Messages
6,114,177
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