Sum portion of row based on multiple column header criteria

Bluefish74274

New Member
Joined
Dec 30, 2020
Messages
6
Office Version
  1. 365
Platform
  1. Windows
Hi folks! I'm new to the forum so please forgive any newbie faux pas! I've been scouring the web this afternoon (as well as this forum, which I love!) for a solution to my problem. I have monthly metrics (sales, margin, etc.,) for actuals, budget and last year for various fruit. On another tab in my excel spreadsheet, I'd like to be able to aggregate each metric to quarterly or FY totals. So for example, I'd like Q4 Actual sales or Q4 sales margin for last year. Unfortunately sumproduct is not an option as my raw data is 1K columns wide. Also, I realize that I could append subtotals to the raw data which would significantly widen the data and would be very labor intensive. Was hoping this could be done with sumif +index + match, however I tried using '&' to concatenate the multiple match column criteria (Sales + Actuals + Q4), but as you probably already know, the array formula wouldn't work with sumif. I'm hoping there is a solution that doesn't require VBA code, so please bring it on!! Please let me know if you need anything further.
 

Attachments

  • Capture.JPG
    Capture.JPG
    131.2 KB · Views: 59
Taking a slightly different approach, this is the most realistic automation of the formula entry that I can come up with. Note that for set up purposes I changed July to Q1 in the raw data on the assumption that you will need all 4 quarters in the actual file.

Note that only B17:F17 are hardcoded values (manual entry) the rest is all done by formula.
Cell Formulas
RangeFormula
B18:U18,B16:U16B16=INDEX(5:5,AGGREGATE(15,6,COLUMN($B5:$Y5)/($B$6:$Y$6="Q1"),COUNTIF($B$17:B$17,"Q1")))
G17:U17G17=B17
A18:A24A18=A8
B19:U24B19=SUMIFS(INDEX($B$9:$Y$14,MATCH($A19,$A$9:$A$14,0),0),$B$5:$Y$5,B$16,$B$6:$Y$6,IF(B$17="FY","*",B$17),$B$7:$Y$7,B$18)
 
Upvote 0
Solution

Excel Facts

How to calculate loan payments in Excel?
Use the PMT function: =PMT(5%/12,60,-25000) is for a $25,000 loan, 5% annual interest, 60 month loan.
Thanks @jasonb75! I think your solution with xlookup and filter functions would work perfectly if I had the most recent office 365 updates. Looks like MS began rolling out July 2020. Will have to contact my sys admin to find out when I'll see the updates! In the mean time will use work around solution. Appreciate all your help!
 
Upvote 0

Forum statistics

Threads
1,213,517
Messages
6,114,085
Members
448,548
Latest member
harryls

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