shorten multiple Index Match formula

psrs0810

Well-known Member
Joined
Apr 14, 2009
Messages
1,109
I have this long drawn out Index Match-ing formula that I am hoping can be shortened.


=ROUND((OFFSET(INDEX(K$1:K$2094,MATCH($A2304,$A$1:$A$2094,0)),6,0)*$D2304)+IFERROR((OFFSET(INDEX(K$1:K$2094,MATCH($A2305,$A$1:$A$2094,0)),6,0)*$D2305),0)+IFERROR((OFFSET(INDEX(K$1:K$2094,MATCH($A2306,$A$1:$A$2094,0)),6,0)*$D2306),0)+IFERROR((OFFSET(INDEX(K$1:K$2094,MATCH($A2307,$A$1:$A$2094,0)),6,0)*$D2307),0)+IFERROR((OFFSET(INDEX(K$1:K$2094,MATCH($A2308,$A$1:$A$2094,0)),6,0)*$D2308),0)+IFERROR((OFFSET(INDEX(K$1:K$2094,MATCH($A2309,$A$1:$A$2094,0)),6,0)*$D2309),0)+IFERROR((OFFSET(INDEX(K$1:K$2094,MATCH($A2310,$A$1:$A$2094,0)),6,0)*$D2310),0)+IFERROR((OFFSET(INDEX(K$1:K$2094,MATCH($A2311,$A$1:$A$2094,0)),6,0)*$D2311),0)+IFERROR((OFFSET(INDEX(K$1:K$2094,MATCH($A2312,$A$1:$A$2094,0)),6,0)*$D2312),0)+IFERROR((OFFSET(INDEX(K$1:K$2094,MATCH($A2313,$A$1:$A$2094,0)),6,0)*$D2313),0)+IFERROR((OFFSET(INDEX(K$1:K$2094,MATCH($A2314,$A$1:$A$2094,0)),6,0)*$D2314),0),0)

Please let me know
thanks
 

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,)
=ROUND(SUM(SUBTOTAL(6,OFFSET($A$1,MATCH($A$2304:$A$2314,$A$1:$A$2094,0)+5,10),$A$2304:$A$2314)),0)

NVM larger sample.... wrong
 
Last edited:
Upvote 0
The OFFSET part correctly returns the values in Column A but for some reason SUMPRODUCT can't evaluate the array????

=SUMPRODUCT(OFFSET($A$1,MATCH($A$2304:$A$2314,$A$1:$A$2094,0)+5,10),$A$2304:$A$2314) = 0

But using F9 to evaluate returns:

=SUMPRODUCT({7;8;9;10;11;12;13;14;15;16;17},{1;2;3;4;5;6;7;8;9;10;11}) = 902
 
Last edited:
Upvote 0
This gives the right answer for my test data:

=ROUND(SUMPRODUCT(SUBTOTAL(6,OFFSET($A$1,MATCH($A$2304:$A$2314,$A$1:$A$2094,0)+5,10)),$A$2304:$A$2314), 0)
 
Last edited:
Upvote 0

Forum statistics

Threads
1,213,561
Messages
6,114,316
Members
448,564
Latest member
ED38

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