Index Match multiple criteria

tiredofit

Well-known Member
Joined
Apr 11, 2013
Messages
1,825
Office Version
  1. 365
  2. 2019
Platform
  1. Windows
I am trying to create an index match formula based on multiple criteria, as per this article:

Rich (BB code):
https://exceljet.net/formula/index-and-match-with-multiple-criteria

In particular, I would like to use the NON-ARRAY formula, as stated in the article, ie:

Rich (BB code):
[FONT=Verdana,Arial,Tahoma,Calibri,Geneva,sans-serif]=INDEX(rng1,MATCH(1,INDEX((A1=rng2)*(B1=rng3)*(C1=rng4),0,1),0))
[/FONT]

This is my code but it errors on the last line:

Rich (BB code):
[FONT=Verdana,Arial,Tahoma,Calibri,Geneva,sans-serif]    Dim rng1 As Range
    
    With Sheet1
    
        Set rng1 = .Range(.Cells(5, 5), .Cells(11, 5))[/FONT]
[FONT=Verdana,Arial,Tahoma,Calibri,Geneva,sans-serif]
    End With[/FONT]
[FONT=Verdana,Arial,Tahoma,Calibri,Geneva,sans-serif]
    Dim rng2 As Range
    
    With Sheet1
    
        Set rng2 = .Range(.Cells(5, 2), .Cells(11, 2))[/FONT]
[FONT=Verdana,Arial,Tahoma,Calibri,Geneva,sans-serif]
    End With
    
    Dim rng3 As Range
    
    With Sheet1
    
        Set rng3 = .Range(.Cells(5, 3), .Cells(11, 3))

[/FONT]
[FONT=Verdana,Arial,Tahoma,Calibri,Geneva,sans-serif]    End With
    
    Dim rng4 As Range
    
    With Sheet1
    
        Set rng4 = .Range(.Cells(5, 4), .Cells(11, 4))[/FONT]
[FONT=Verdana,Arial,Tahoma,Calibri,Geneva,sans-serif]    
    End With
 
    Dim abc
    
    abc = Application.Index(rng1, Application.Match(1, Application.Index(("T-shirt" = rng2) * ("Large" = rng3) * ("Red" = rng4), 0, 1), 0))

Can someone please tell me what is wrong?

Thanks


[/FONT]
 
Last edited:

Excel Facts

How to total the visible cells?
From the first blank cell below a filtered data set, press Alt+=. Instead of SUM, you will get SUBTOTAL(9,)
Try this way

Code:
Sub test()
  Dim rng1 As Range, rng2 As Range, rng3 As Range, rng4 As Range, abc As Variant
  Set rng1 = Range(Cells(5, 5), Cells(11, 5))
  Set rng2 = Range(Cells(5, 2), Cells(11, 2))
  Set rng3 = Range(Cells(5, 3), Cells(11, 3))
  Set rng4 = Range(Cells(5, 4), Cells(11, 4))
  abc = Evaluate("Index(" & rng1.Address & ",Match(1,(""T-shirt""=" & rng2.Address & ")*" & _
    "(""Large""=" & rng3.Address & ")*(""Red""=" & rng4.Address & "),0))")
End Sub
 
Upvote 0

Forum statistics

Threads
1,213,504
Messages
6,114,020
Members
448,543
Latest member
MartinLarkin

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