SOLVED

Tabular Pivot Table with Excel Lambda and new array functions

Brass Contributor

Hello everyone,

 

I've been learning and practicing Lambda helper functions for the last few months and I'm amazed by advanced techniques, especially with those that handle arrays of arrays - @Peter Bartholomew's thunks  and @Sergei Baklan's magic solution DROP/REDUCE/VSTACK.

 

I need a little help with a problem that seems simpler than that.

 

How can we replicate a tabular pivot table using Excel's new set of functions in the most efficient way and one single formula?

 

I have attached a simple example containing two columns of hierarchized categories and one of values that must be added up.

 

Thanks in advance!

 

brunomerola_0-1661799309987.png

4 Replies

@brunomerola 

This is intended as a 'starter for one' to allow for further refinement.  Because your data is hierarchical and the Category starts the class as its first character, it is only necessary to work with the category.

The basic ways of getting conditional sums are to use SUMIFS over the source data or to FILTER the data and sum each category.

= LET(
    category, SORT(UNIQUE(Data[Category])),
    sumValue, SUMIFS(Data[Value], Data[Category], category),
    HSTACK(category, sumValue)
  )

Alternatively

= LET(
    category, SORT(UNIQUE(Data[Category])),
    sumValue, MAP(category, LAMBDA(cat,
      SUM(FILTER(Data[Value], Data[Category]= cat)))
    ),
    HSTACK(category, sumValue)
  )

Many refinements are possible but it is up to you to decide what is important.  For example interlacing subtotals presents a bit of a challenge but may not be needed.

 

Thank you very much for the quick response, but how can we actually interlace class and subtotals and sort each group of categories inside each class?

The example has categories that start with the class letter, but this will not be the case in my real case application.
best response confirmed by brunomerola (Brass Contributor)
Solution

@brunomerola 

This might explain my hesitance getting involved with issues of layout!

= LET(
    wildcards,      IFNA(HSTACK(UNIQUE(Data[Class]), "*"),"*"),
    distinct,       SORT(VSTACK(wildcards, UNIQUE(Data[[Class]:[Category]])),{1,2}),
    class,          CHOOSECOLS(distinct,1),
    category,       CHOOSECOLS(distinct,2),
    sumValue,       SUMIFS(Data[Value], Data[Class], class, Data[Category], category),
    outputClass,    IF(category="*", class, ""),
    outputCategory, IF(category<>"*", category, ""),
    output,         HSTACK(outputClass, outputCategory, sumValue),
    totalrow,       HSTACK("Total", "", SUM(Data[Value])),
    VSTACK(output, totalrow) 
 )

image.png

This is a game changer. Thank you so much.
1 best response

Accepted Solutions
best response confirmed by brunomerola (Brass Contributor)
Solution

@brunomerola 

This might explain my hesitance getting involved with issues of layout!

= LET(
    wildcards,      IFNA(HSTACK(UNIQUE(Data[Class]), "*"),"*"),
    distinct,       SORT(VSTACK(wildcards, UNIQUE(Data[[Class]:[Category]])),{1,2}),
    class,          CHOOSECOLS(distinct,1),
    category,       CHOOSECOLS(distinct,2),
    sumValue,       SUMIFS(Data[Value], Data[Class], class, Data[Category], category),
    outputClass,    IF(category="*", class, ""),
    outputCategory, IF(category<>"*", category, ""),
    output,         HSTACK(outputClass, outputCategory, sumValue),
    totalrow,       HSTACK("Total", "", SUM(Data[Value])),
    VSTACK(output, totalrow) 
 )

image.png

View solution in original post