Changing columns in Sumproduct with cell references

dazednconfuzed

New Member
Joined
Nov 22, 2017
Messages
4
Hi Guys, sorry if this has been covered before, I searched a lot but couldnt find an answer.

In my formula, I need to change columns with cell references. My formula is:

=SUMPRODUCT(--($C$3:$C$57=$BG3),BD$3:BD$57,H$3:H$57)

I have weights in columns BD, BE and BF. In the above formula, I need to be able to change the weights to column BD, BE and BF.

I thought that if I have a row at the top of the column, I can then manually enter the text BD, BE or BF and have a formula that changes the weights based on what I entered.

I cant seem to figure this out. Thanks.
 

Excel Facts

Save Often
If you start asking yourself if now is a good time to save your Excel workbook, the answer is Yes
Welcome to Mr Excel forum

Maybe this

Put, say, in A2 the column of interest: BD,BE or BF

Try this formula
=SUMPRODUCT(--($C$3:$C$57=$BG3),INDEX(BD$3:BF$57,0,MATCH(A$2,{"BD";"BE";"BF"},0)),H$3:H$57)

I hope kids do not get hungry ;)

M.
 
Last edited:
Upvote 0
My kids thank you, Sir!

I figured out an easier way (its a wonder what hunger does to a man's motivation). I decided to use named ranges with INDIRECT function. Worked like a charm. Off to Chinese buffet now
 
Upvote 0
Learned something new today, thanks. In my worksheet there are multiple columns in which I need to indicate the weights. So in your example, it wont be just A2 with the weight name but A2, B2 and C2. Dont mean to impose but if you get a moment please update your formula for my case. Thanks.
 
Upvote 0
Learned something new today, thanks. In my worksheet there are multiple columns in which I need to indicate the weights. So in your example, it wont be just A2 with the weight name but A2, B2 and C2. Dont mean to impose but if you get a moment please update your formula for my case. Thanks.

Not sure i understand what you are trying to do, but i think all you have to do is to adjust on each formula: the cell reference, the ranges and the array in the INDEX/MATCH part (in blue)
=SUMPRODUCT(--($C$3:$C$57=$BG3),INDEX(BD$3:BF$57,0,MATCH(A$2,{"BD";"BE";"BF"},0)),H$3:H$57)

To understand what this part does
INDEX(range,0, column_num)
the 0 (second argument: row_num) forces the formula to provide an array composed of all rows (in the case, rows 3:57)
MATCH gets the relative position, of the value entered in A2, in the array {"BD";"BE";"BF"), that is: if A2 = BD, match returns 1; if BE, returns 2; if BF returns 3

So with A2, for example, equal BE the INDEX/MATCH returns all rows of the second column of the range BD3:BF57 that is exactly BE3:BE57

Hope i made myself clear

M.
 
Upvote 0

Forum statistics

Threads
1,224,820
Messages
6,181,159
Members
453,021
Latest member
Justyna P

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