Results 1 to 5 of 5

Thread: Improvements for function: Sum only Number Columns, maintain column names

  1. #1
    Conjurer Nick Burns's Avatar
    Join Date
    May 2017
    Posts
    138
    Articles
    0
    Excel Version
    Office 365

    Improvements for function: Sum only Number Columns, maintain column names



    Register for a FREE account, and/
    or Log in to avoid these ads!

    I created a function to dynamically sum all Numeric columns AND maintain all the columns.

    I also added the option to make any column the Count column.

    Click image for larger version. 

Name:	DynamicGroup.PNG 
Views:	20 
Size:	58.7 KB 
ID:	10671

    Here's the function:
    Code:
    (tbl as table, GroupByColumnList as list, optional CountColumnName as nullable text) as table =>
    let
        TableSchema = Table.SelectColumns(Table.Schema(tbl),{"Name","Kind"}),
        NumberColumns = Table.SelectColumns(Table.SelectRows(TableSchema, each ([Kind] = "number")),{"Name"})[Name],
        NonNumberColumns = List.Difference(Table.SelectColumns(Table.SelectRows(TableSchema, each ([Kind] <> "number")),{"Name"})[Name],GroupByColumnList & {CountColumnName}),
        SumColumns = List.Transform(NumberColumns, (ColName) => {ColName, (Partition)=> List.Sum(Table.Column(Partition,ColName)), type nullable number}),
        NonSumColumns = List.Transform(NonNumberColumns, each {_,  each null, type nullable text }),
        CountColumns = List.Transform({CountColumnName}, each {_,  each Table.RowCount(_), Int64.Type}),
        AllColumns = if CountColumnName = null then SumColumns & NonSumColumns else SumColumns & NonSumColumns & CountColumns,
        DynamicGroup = Table.Group(tbl, GroupByColumnList, AllColumns),
        ReorderColumns = Table.SelectColumns(DynamicGroup,Table.ColumnNames(tbl)),
        Result = if CountColumnName = null then ReorderColumns else Table.RenameColumns(ReorderColumns,{{CountColumnName, "Count"}})
    in
        Result
    I was just wondering if there are any improvements that could be made.


    EDIT: (Sorry Column1 was inserted when I loaded the totals, that column shouldn't be there).
    Attached Files Attached Files
    Last edited by Nick Burns; 2021-10-22 at 06:51 AM.
    Oh... by the way, YOU'RE WELCOME!

  2. #2
    Administrator Ken Puls's Avatar
    Join Date
    Mar 2011
    Location
    Nanaimo, BC, Canada
    Posts
    2,459
    Articles
    43
    Blog Entries
    14
    Excel Version
    Excel Office 365 Insider
    Hi Nick,

    Just had a quick look - not enough time to recommend any improvements - I was just curious to see what you had. I think I'd need to spend more time carefully examining all the list management you have in there to really get a grasp on whether it could be improved much.

    One note... you could save one step as your "tbl" step just references the previous Changed Type step (just rename the Changed Type step and it should work the same.)
    Ken Puls, FCPA, FCMA, MS MVP

    Learn to Master Your Data at the Power Query Academy (the world's most comprehensive online Power Query training), with my book M is for Data Monkey, or our new Power Query Recipe cards!

    Main Site: http://www.excelguru.ca -||- Blog: http://www.excelguru.ca/blog -||- Forums: http://www.excelguru.ca/forums
    Check out the Excelguru Facebook Fan Page -||- Follow Me on Twitter

    If you've been given VBA code (a macro) for your solution, but don't know where to put it, CLICK HERE.

  3. #3
    Conjurer Nick Burns's Avatar
    Join Date
    May 2017
    Posts
    138
    Articles
    0
    Excel Version
    Office 365
    Quote Originally Posted by Ken Puls View Post
    Hi Nick,

    Just had a quick look - not enough time to recommend any improvements - I was just curious to see what you had. I think I'd need to spend more time carefully examining all the list management you have in there to really get a grasp on whether it could be improved much.

    One note... you could save one step as your "tbl" step just references the previous Changed Type step (just rename the Changed Type step and it should work the same.)
    Ah, you must be talking about the FunctionSteps query in the file.
    That was my "wire-framing" of the actual function (fnDynamicGroup) - hardcoding variables and such. fnDynamicGroup is not derived from FunctionSteps.
    Oh... by the way, YOU'RE WELCOME!

  4. #4
    Conjurer Nick Burns's Avatar
    Join Date
    May 2017
    Posts
    138
    Articles
    0
    Excel Version
    Office 365
    I did another take on it, though I'm not sure if it's "better", but it is less steps and it maintains the original Column Types, unless the Count column is provided.
    Code:
    (tbl as table, GroupByColumnList as list, optional CountColumnName as nullable text) as table =>
    let
        SelectedColumns = Table.SelectColumns(tbl,List.Difference(Table.ColumnNames(tbl),GroupByColumnList)),
        TableSchema = Table.SelectColumns(Table.Schema(SelectedColumns),{"Name","Kind"}),
        AddCustom = Table.AddColumn(TableSchema, "Custom", 
                                                          each {[Name], 
                                                          if [Name] = CountColumnName then each Table.RowCount(_) else if [Kind] = "number" then (Partition) => List.Sum(Table.Column(Partition,[Name])) else each null,  
                                                          if [Name] = CountColumnName then type nullable number else Type.TableColumn(Value.Type(tbl),[Name])}),
        DynamicGroup = Table.Group(tbl, GroupByColumnList, AddCustom[Custom]),
        ReorderColumns = Table.SelectColumns(DynamicGroup,Table.ColumnNames(tbl)),
        Result = if CountColumnName = null then ReorderColumns else Table.RenameColumns(ReorderColumns,{{CountColumnName, "Count"}})
    in
        Result
    Oh... by the way, YOU'RE WELCOME!

  5. #5
    Conjurer Nick Burns's Avatar
    Join Date
    May 2017
    Posts
    138
    Articles
    0
    Excel Version
    Office 365
    OK, here's my final stab at this.
    This may be best I can do, it only deals with the Column List and the meta data of the columns. No interim tables.

    Code:
    (tbl as table, GroupByColumnList as list, optional CountColumnName as nullable text) as table =>
    let
        AggregateColumns = List.Transform(
              List.Difference(Table.ColumnNames(tbl),GroupByColumnList), 
                  each {_, 
                  if _ = CountColumnName then each Table.RowCount(_) else if Type.Is(Type.TableColumn(Value.Type(tbl),_),type nullable number) then (T) => List.Sum(Table.Column(T,_)) else each null,
                  if _ = CountColumnName then type nullable number else Type.TableColumn(Value.Type(tbl),_)}),
        DynamicGroup = Table.Group(tbl, GroupByColumnList, AggregateColumns),
        ReorderColumns = Table.SelectColumns(DynamicGroup,Table.ColumnNames(tbl)),
        Result = if CountColumnName = null then ReorderColumns else Table.RenameColumns(ReorderColumns,{{CountColumnName, "Count"}})
    in
        Result
    Oh... by the way, YOU'RE WELCOME!

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •