Forum Discussion
SUMIFS formulas in different Layout
- Nov 21, 2021
sure. Switch is like a multiple IF statement. Instead of IF A=1 then ... ELSE IF A=2 then ... ELSE IF A=3 ... where you keep doing comparison against the same value, SWITCH just takes that one input and will SWITCH the output. If you type =SWITCH( into a cell then excel can show you the parameters but basically the value in question then pairs of condition, output so if the value meets a condition it will output that part.
INDEX will take an array or table and return the value or array that you specify. So an array of a,b,c,d,e,f and you index 3 then you get c. If it is a table you can specify both row and column to get a single value or just the row or just the col to get back the corresponding row or column. In your case here is the formula broken out with notes. I added a periods to create indenting but the word wrap may still make it confusing:
=SWITCH($E6, <<<this is the check value
"Forecast", <<<this is the first condition/check for switch
... IFERROR(SUMIFS(
...... INDEX('Forecast Input'!$A:$BO, <<< this is the range for the index
............. , <<< this is the row for the index (i.e. return all rows
.............. MATCH(TEXT($A6,"0"),'Forecast Input'!$1:$1,0)), <<< this match find the column you want for the index
........ 'Forecast Input'!$A:$A, Master!$C6, <<<this is a conditional pair for sumifs
........ 'Forecast Input'!$D:$D, Master!$D6, <<<this is a conditional pair for sumifs
........ [[[ADD RANGE TO CHECK , CONDITIONAL]]] ) <<<this is a conditional pair for sumifs
... ,0), <<< this is the value to return if error found
"Actual", <<<this is the second condition/check for switch
... SUMIFS(
......... 'CMO Input'!$Q:$Q,
......... 'CMO Input'!$E:$E, Master!$A6,
........ 'CMO Input'!$C:$C, Master!$C6,
........ 'CMO Input'!$AJ:$AJ, Master!$D6,
....... 'CMO Input'!$AU:$AU, Master!F$2),
"") <<< this is the default result for switch (i.e. if it didn't match any of the above
excel_learner I created a 'master formula for that column using SWITCH instead of IFS. as opposed to Martin_Weiss using OFFSET I used INDEX which is probably 6 vs 1/2 doz. I included the added criteria but my problem and why I didn't post earlier and had to come back to it is that I found out that your LDP values on the Master do not match your LDP values on the Forecast. I could add even more complexity to the formula but I think it might be better for you to just pick a convention and use it. Here is the formula:
=SWITCH($E10764,
"Forecast",IFERROR(SUMIFS(INDEX('Forecast Input'!$A:$BO,,MATCH(TEXT($A10764,"0"),'Forecast Input'!$1:$1,0)),'Forecast Input'!$A:$A,Master!$C10764,'Forecast Input'!$D:$D,Master!$D10764),0),
"Actual",SUMIFS('CMO Input'!$Q:$Q,'CMO Input'!$E:$E,Master!$A10764,'CMO Input'!$C:$C,Master!$C10764,'CMO Input'!$AJ:$AJ,Master!$D10764,'CMO Input'!$AU:$AU,Master!F$2),
"")also it could be cleaner if you have Excel 365 and we could use LET() and FILTER() statements but you didn't tell us what version of Excel you are using.
In the attached you can see the formula and if you ctrl-down in column G you will find where I figured out the problem with the LDP naming.
- excel_learnerNov 17, 2021Brass Contributor
Hi mtarler
Thank you I have now changed the LDP Values to match master sheet, when you said I could add even more complexity to the formula, in what way may I ask please ? I am using office 365, could you possibly show a cleaner formula with LET() and FILTER().- mtarlerNov 18, 2021Silver Contributorsorry my comment "I could add even more complexity" was intended w/r to adding additional parts to use partial matches to match the LDP values but you fixed that. As for using LET and FILTER I took a look and tried and find it marginal. I mean using LET you could 'define' all the ranges and such (but you could also do that using the Name Manager) so the formula is clearer what you are pointing to. As for the FILTER or using XMATCH or XLOOKUP function they don't seem to add much since the SUMIFS is doing most of that also. There is some marginal benefit since those functions give an optional parameter for 'if not found' instead of using IFERROR(). so unless there is other reasons, I don't see much point in making the conversion in this case but do recommend you try them out when you have a chance.
- excel_learnerNov 19, 2021Brass Contributor
Hi mtarler
I have used the following formula but don't get any results for actuals also get the wrong totals on forecast for the specific categories.
The formula i used was
=SWITCH($E6,"Forecast",IFERROR(SUMIFS(INDEX('Forecast Input'!$A:$BO,,MATCH(TEXT($A6,"0"),'Forecast Input'!$1:$1,0)),'Forecast Input'!$A:$A,Master!C6,'Forecast Input'!$D:$D,Master!D6),0),"Actual",SUMIFS('CMO Input'!$Q:$Q,'CMO Input'!$E:$E,Master!$A6,'CMO Input'!$C:$C,Master!$C6,'CMO Input'!$AJ:$AJ,Master!$D6,'CMO Input'!$AU:$AU,Master!$F2),"")
I also notice the section of the formula for forecast doesn't have the category criteria from master sheet.
Do you know how I can fix this to get the actuals and forecast based on categories in cells F2, G2, H2 etc of the Master sheet based on criteria of week, Area, LDP,