Activecell.formula variable column number issue

gruntingmonkey

Active Member
Joined
Mar 6, 2008
Messages
417
Office Version
  1. 2016
Platform
  1. Windows
I have code that places a formula into a cell. What I am looking to do is have variable column numbers for E2 & AF2 as these columns will change.

Rich (BB code):
ActiveCell.Formula = "=COUNTIFS(E2,"">=""&Utilities!$F$12,AF2,"">""&Utilities!$H$12)"

I have the code to work out the column numbers but cant work out how to integrate that into the formula

VBA Code:
Cells.Find(What:="Test Search", After:=ActiveCell, LookIn:= _
        xlFormulas, LookAt:=xlPart, SearchOrder:=xlByRows, SearchDirection:= _
        xlNext, MatchCase:=False, SearchFormat:=False).Activate
TestSearchCol = ActiveCell.Column
 
Last edited by a moderator:

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
68,248
Office Version
  1. 365
Platform
  1. Windows
I just don't know how to integrate it into the activecell.formula.
And nor do I if you don't answer my question. ;)
It would also help if you posted all the code.
 

Excel Facts

Whats the difference between CONCAT and CONCATENATE?
The newer CONCAT function can reference a range of cells. =CONCATENATE(A1,A2,A3,A4,A5) becomes =CONCAT(A1:A5)

gruntingmonkey

Active Member
Joined
Mar 6, 2008
Messages
417
Office Version
  1. 2016
Platform
  1. Windows
Lets try this again! Its the last two lines that are the important bits!

VBA Code:
''Match First Text to derive first column
    Sheets("Pivot Data").Select
Cells.Find(What:="Test 1", After:=ActiveCell, LookIn:= _
        xlFormulas, LookAt:=xlPart, SearchOrder:=xlByRows, SearchDirection:= _
        xlNext, MatchCase:=False, SearchFormat:=False).Activate
Test1Column = ActiveCell.Column

''Match Second Text to derive second column
Cells.Find(What:="Test 2", After:=ActiveCell, LookIn:= _
        xlFormulas, LookAt:=xlPart, SearchOrder:=xlByRows, SearchDirection:= _
        xlNext, MatchCase:=False, SearchFormat:=False).Activate
Test2Column = ActiveCell.Column

'''This is the cell that I need the formula to be put into
Range("A2").Select

'''This is the formula that needs to go into the cell - HOWEVER - E2 should be linked in to Test1Column, row 2 & AF2 should be linked in to Test2Column, row 2
    ActiveCell.Formula = "=COUNTIFS(E2,"">=""&Utilities!$F$12,AF2,"">""&Utilities!$H$12)"

Please let me know if this is any clearer.. or not!
 
Last edited:

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
68,248
Office Version
  1. 365
Platform
  1. Windows
Thanks for that, how about
VBA Code:
ActiveCell.FormulaR1C1 = "=and(rc" & test1column & ">=Utilities!r12c6,rc" & test2column & ">Utilities!r12c8)+0"
 
Solution

gruntingmonkey

Active Member
Joined
Mar 6, 2008
Messages
417
Office Version
  1. 2016
Platform
  1. Windows
I'm very sorry for putting that confusingly. Your answer worked a treat.
 
Master Excel Bundle

Excel contains over 450 functions, with more added every year. That’s a huge number, so where should you start? Right here with this bundle.

Forum statistics

Threads
1,152,405
Messages
5,769,881
Members
425,578
Latest member
Ckrysa

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
Top