Forum Discussion
Need help to resolve Excel Formula using Let,Take,index,Sort,Unique,HSTACK,MMULT,TOROW,MONTH.
- Sep 07, 2023
Thank you. Do I understand correctly that csv62719 is you source file. If to avoid Power Query we copy/paste data from it into the sheet in main file, here by formula create massaged range and based on it and month/year/monthid parameters create aggregated result. Workflow is correct?
To add screenshot here, copy it into clipboard, here click on Insert Picture button
after that click by mouse at any place in grey area
Ctrl+V, picture shall be loaded from the clipboard, when it's ready click Done at bottom right.
Back to the sample, I added headers for better understanding, in general you may ignore them.
I guess we need to sum amount for identical Id, Date, Transaction and Type. That could be done by
=LET(
range, $B$2:$G$10,
Id, CHOOSECOLS(range, 1),
date, CHOOSECOLS(range, 2),
transaction, CHOOSECOLS(range, 4),
type, CHOOSECOLS(range, 5),
amount, CHOOSECOLS(range, 6),
groupIndexes, {1,2,4,5},
group, UNIQUE( CHOOSECOLS(range, groupIndexes ) ),
VSTACK({"Id","Date","Transaction","Type","Amount"},
HSTACK(
group,
BYROW( group,
LAMBDA(v, SUM(
FILTER(amount,
(Id = INDEX(v,1,1) )*
(date = INDEX(v,1,2) )*
(transaction = INDEX(v,1,3) )*
(type = INDEX(v,1,4) )
)
) )
)
) )
)
If we would like to filter for the specific year and month as they are defined here
slightly modified formula will be
=LET(
range, $B$2:$G$10,
year, $J$14,
monthNumber, $J$15,
Id, CHOOSECOLS(range, 1),
date, CHOOSECOLS(range, 2),
transaction, CHOOSECOLS(range, 4),
type, CHOOSECOLS(range, 5),
amount, CHOOSECOLS(range, 6),
monthRange, FILTER(range, EOMONTH(date,0) = EOMONTH( DATE(year,monthNumber,1), 0 )),
groupIndexes, {1,2,4,5},
group, UNIQUE( CHOOSECOLS(monthRange, groupIndexes ) ),
VSTACK({"Id","Date","Transaction","Type","Amount"},
HSTACK(
group,
BYROW( group,
LAMBDA(v, SUM(
FILTER(amount,
(Id = INDEX(v,1,1) )*
(date = INDEX(v,1,2) )*
(transaction = INDEX(v,1,3) )*
(type = INDEX(v,1,4) )
)
) )
)
) )
)
Your initial formula sum amounts for the unique Id (only one column) in a given month. It's can't be adjusted directly for the few unique columns.
Another way is to create PivotTable, something like
Please check in attached file if that close to what you'd like to receive.
Once again thank you for your kind help. It has been a long three weeks since I started this project.