Sub Total Row within an Array Formula

Peter Davison

Active Member
Joined
Jun 4, 2020
Messages
451
Office Version
  1. 365
Platform
  1. Windows
I'm currently getting an array from this formula
=UNIQUE(CHOOSECOLS(FILTER('User Analysis'!$G$12:$AG$1000,'User Analysis'!$G$12:$G$1000<>""),1,2,3,4,10,20))
In Column C (Text) (which is column 3 from the choose columns feature)I want to add to this formula to make it sub total all value columns (10 and 20) at each break point in Column C
Is this possible
 

Excel Facts

Which Excel functions can ignore hidden rows?
The SUBTOTAL and AGGREGATE functions ignore hidden rows. AGGREGATE can also exclude error cells and more.
Can you post some sample data.

MrExcel has a tool called “XL2BB” that lets you post samples of your data that will allow us to copy/paste it to our Excel spreadsheets, so we can work with the same copy of data that you are. Instructions on using this tool can be found here: XL2BB Add-in

Note that there is also a "Test Here” forum on this board. This is a place where you can test using this tool (or any other posting techniques that you want to test) before trying to use those tools in your actual posts.
 
Upvote 0
Thank you for getting back to me.
There are a couple of reasons I wouldn't be able to send the data on XL2BB, firstly the file is very large and links to several other data files and secondly it is sensitive customer data.
Is there any other way I can help in this?

Here is a snippet showing that I want to have a subtotal break (Row) based on Col C (Department Name) as part of the formula because the length of each department can vary by store.
Hope I have explained that okay

The sub total would add up on the two value columns (Height Adjusted - F & Adj Gross Final - G)

1701692106309.png
 
Upvote 0
You could try
Excel Formula:
=LET(d,UNIQUE(CHOOSECOLS(FILTER('User Analysis'!$G$12:$Z$1000,'User Analysis'!$G$12:$G$1000<>""),1,2,3,4,10,20)),u,UNIQUE(INDEX(d,,2)),SORTBY(VSTACK(d,CHOOSE(SEQUENCE(,6),u,"","","",SUMIFS('User Analysis'!Z:Z,'User Analysis'!H:H,u),SUMIFS('User Analysis'!P:P,'User Analysis'!H:H,u))),VSTACK(SEQUENCE(ROWS(d)),XMATCH(u,INDEX(d,,2),0,-1))))
but without any data I have no way of testing it.
 
Upvote 0
Solution
That is absolutely amazing.
You are a real star!
I was trying everything to avoid a Pivot Table
I can't wait for Pivot and Group By to arrive in standard 365
Thanks Again
 
Upvote 0
You're welcome & thanks for the feedback.
 
Upvote 0

Forum statistics

Threads
1,224,818
Messages
6,181,150
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