SUM/SUMIFS with Conditional Array & Wildcards

ReturnAg08

New Member
Joined
Nov 2, 2016
Messages
7
Hello!

I'm working with the following section of a formula:

SUM(SUMIFS('All Facilities'!$AC:$AC,'All Facilities'!$F:$F,$C$29,'All Facilities'!$AR:$AR,{"Operating","2017*"}))

It's working just fine (and yes, entered with ctrl+shift+enter), but I want to make an adjustment to it: That last part at the end where I'm searching for anything with 2017 and a wildcard, I'd like to have the 2017 part reference a specific cell, but it still needs the wildcard. For example, something I look up would be 2017 Q1, or 2017 Q2. If I switch to a cell reference I could change the cell from 2017 to 2018 and it would now find 2018 Q1 without having to manually update all of my formulas.

Let's assume the year is in cell A1. I've tried {"Operating","A1&*"} or {"Operating",A1&"*"} or {"Operating","*"&A1&"*"}, but those don't seem to work. Is this possible to do?
 

Excel Facts

How can you turn a range sideways?
Copy the range. Select a blank cell. Right-click, Paste Special, then choose Transpose.
Try

=SUMPRODUCT(SUMIFS('All Facilities'!$AC:$AC,'All Facilities'!$F:$F,$C$29,'All Facilities'!$AR:$AR,CHOOSE({1,2},"Operating",A1&"*")))
confirmed with just Enter

Hope this helps.

M.
 
Upvote 0
Marcelo,

That definitely worked! Thanks for that.

I'm not sure why it worked though? Can you explain why to use the CHOOSE function here, and why it doesn't need the ctrl+shift+enter to confirm it?
 
Upvote 0
You are welcome. Thanks for the feedback.

About the formula:
1. The function CHOOSE with an array {1,2} as its first argument creates the desired array , ie, it makes an array with 2 elements: "Operating" and the concatenation of the value in A1 with the wildcard *.
2. SUMPRODUCT deals with arrays without Ctrl+Shift+Enter.
3. To see what the formula does, step by step, try Formulas > Evaluate formula

M.
 
Last edited:
Upvote 0

Forum statistics

Threads
1,223,903
Messages
6,175,289
Members
452,631
Latest member
a_potato

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