Array INDEX-MATCH with dynamic criteria and SUMPRODUCT?

BombCenter

New Member
Joined
Aug 31, 2011
Messages
19
Hey all,

I'm looking for a way to dynamically lookup markup rates from another worksheet, multiply them by the correct prices for matching products on the sales worksheet, and display it as a total markup amount beneath the subtotal. Some of the items, however, need to be excluded from the calculation based on product type. Here's some grossly oversimplified test data of what I'm trying to accomplish:

Sales Worksheet
Product Name:Product Type:Cost:Qty:Price:
AppleFruit122
DrugsNoMarkup1001100
BroccoliVegetable212
BreadGrain313
BeerNoMarkup428
FishMeat9218
CheeseDairy313
CigarettesNoMarkup10110
CookiesDelicious36001800
Subtotal:1946
Markup/Margin:(Excl. NoMarkup)?
Total:

<tbody>
</tbody>

Rates Worksheet
Product Type:Markup %:Tax Rate:
Fruit.05.0775
Vegetable.05.0775
Grain.10.0775
Meat.20.0775
Dairy.10.0775
Delicious.50.0775

<tbody>
</tbody>

I was thinking that I should be able to do something with SUMPRODUCT and INDEX-MATCH, but so far have had no joy.
E.g., =SUMPRODUCT(Sales!Product.Price, INDEX(Rates!Product.Markup, MATCH(Sales!Product.Type, Rates!Product.Type, 0), 1))

A similar INDEX-MATCH approach has worked thus far for calculating the final product price (with markup) on a per-line basis, but being able to calculate the aggregate amount formulaically would be immensely helpful. I'd prefer not to use helper columns, as the actual spreadsheet has 40ish Sales worksheets each with 60ish columns, and adding helper columns to each would be painstaking.

I feel like I'm part of the way there but am missing something key...

Any help would be appreciated.

Thanks!
 

Excel Facts

Spell Check in Excel
Press F7 to start spell check in Excel. Be careful, by default, Excel does not check Capitalized Werds (whoops)
Maybe...

=SUMPRODUCT(Sales!Product.Price,SUMIF(Rates!Product.Type,Sales!Product.Type,Rates!Product.Markup))

M.
 
Upvote 0
Maybe...

=SUMPRODUCT(Sales!Product.Price,SUMIF(Rates!Product.Type,Sales!Product.Type,Rates!Product.Markup))

M.

Won't this just sum all the markup percentages in Rates!Product.Markup (that match Product.Type) and multiply by Sales!Product.Price?
Does SUMIF return an array?
Either way I applied it to my worksheet(s) and no joy. =(
 
Upvote 0
The formula multiply each Price by the respective Markup in sheet Rates, and add all the results.
Is not that what you want? If not, explain better the expected outcome and how to obtain it.
About SUMIF: note that its second parameter is an array, not a single value, so it returns an array.

M.
 
Upvote 0
Using your data sample in post 1 and named ranges (Scope = Worksheet) the formula returned 904.4 for me
Isn't it the desired result?

M.
 
Upvote 0
Your succinct description is absolutely what I'm looking for.
Turns out I wasn't implementing your solution correctly.
Your solution works perfectly, I accidentally reversed the Product.Type in the SUMIF clause. :oops:

Cheers! And thanks so much for all your help. I owe you a beer. (y)
 
Upvote 0

Forum statistics

Threads
1,215,427
Messages
6,124,830
Members
449,190
Latest member
rscraig11

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