VBA Reference an open workbook within a dynamic formula

leatherhen99

New Member
Joined
Dec 17, 2019
Messages
27
Office Version
  1. 365
Platform
  1. Windows
Good Day all!

I appreciate the ability to read others posts and make sense of my own code...but this is a doozy! I have read so many posts, and I know it's probably a missing single/double quote... or maybe I'm missing it all together...

I have 3 workbooks open and I have been able to store the month in a function... and I can get the workbook to open to the correct sheet... but now, my index/match formula is giving me some issues.

Here's what I've written so far:

VBA Code:
Dim ws As Worksheet
    Dim wb As Workbook
    Dim wb1 As Workbook
    Dim wb2 As Workbook
    Dim wb3 As Workbook
    Dim ws1 As Worksheet
    Dim addmonth As Variant

    Set wb1 = ActiveWorkbook
        'wb1= Flex Reports Template
    Workbooks("FLEX Data 2021").Activate
    Set wb2 = ActiveWorkbook
        ' wb2= Flex Data 2021
    Workbooks("Flex Team Reporting").Activate
    Set wb3 = ActiveWorkbook
        'wb3= Flex Team Reporting
    wb1.Activate

    Sheets("WFMs").Select
'display Enter_Month form
    addmonth = Enter_Month.GetMonth
'if cancel is pressed, exit sub
    If Val(addmonth) = vbCancel Then Exit Sub

'On Template, enter month into A4, and paste into all rows of table
    Range("A4").Select
    Range("A4").Value = addmonth & Year(Date)
    ActiveCell.Copy
    Range(Selection, Selection.End(xlDown)).Select
    ActiveSheet.Paste

    wb2.Activate
    Sheets(addmonth).Select
    Set ws1 = ActiveSheet
      

'Paste the formula provided into C4 and copy into rows/columns for all employees
    wb1.Activate
    Range("C4").Select
    ActiveCell.FormulaR1C1 = _
        "=index('[" & wb2 & "]" & ws1 & "'!" & r4c4:r37c13," & _
        "match(rc2,"'[" & wb2 & "]" & ws1 & "'!" & r4c2:r37c2,0),"match(r3c,"'[" & wb2 & "]" & ws1 & "'!" & r3c4:r3c13,0))"
        
       ' "=INDEX('[" & wb2 & "]" & ws1 & "'!R4C4:R37C13",MATCH(RC2,[" & wb2 & "]" & ws1 & "!R4C2:R37C2",0)," & _
        '    "MATCH(R3C,[" & wb2 & "]" & ws1 & "!R3C4:R3C13",0))"

The formula should be going to wb2, the correct month, and matching the agent's name with the header and providing the data. I've written the formula several times and then commented them out...

Any help would be greatly appreciated!!! Thank you!
Heather
 

Excel Facts

What did Pito Salas invent?
Pito Salas, working for Lotus, popularized what would become to be pivot tables. It was released as Lotus Improv in 1989.
How about
VBA Code:
    ActiveCell.FormulaR1C1 = _
        "=index('[" & wb2.Name & "]" & ws1.Name & "'!r4c4:r37c13,match(rc2,'[" & wb2.Name & "]" & ws1.Name & "'!r4c2:r37c2,0),match(r3c,'[" & wb2.Name & "]" & ws1.Name & "'!r3c4:r3c13,0))"
 
Upvote 0
Solution
How about
VBA Code:
    ActiveCell.FormulaR1C1 = _
        "=index('[" & wb2.Name & "]" & ws1.Name & "'!r4c4:r37c13,match(rc2,'[" & wb2.Name & "]" & ws1.Name & "'!r4c2:r37c2,0),match(r3c,'[" & wb2.Name & "]" & ws1.Name & "'!r3c4:r3c13,0))"
Thank you!!! That worked beautifully!!! I cannot thank you enough!!!
 
Upvote 0
You're welcome & thanks for the feedback.
 
Upvote 0

Forum statistics

Threads
1,223,888
Messages
6,175,208
Members
452,618
Latest member
Tam84

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