Results 1 to 10 of 10

Thread: Sum multiple columns in PQ

  1. #1

    Sum multiple columns in PQ



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

    So, this should be relatively simple, but for some reason I can't seem to figure it out. I have 7 columns in PQ, each with numeric values formatted as whole numbers. I need to create a custom column that contains the sum of the original 7 columns.

    If I only use two columns I can easily do =[column.1]+[column.2] and it works fine. But if I do =[column.1]+[column.2]+[column.3] ... I get nothing. I have also tried:

    List.Sum([column1.],[column.2],[column.3]) but all I get is errors. The one I see the most is "cannot convert null to type list". Anyway, I have spent way too long on this and yet have gotten nowhere. Any help is appreciated.
    Brendan

  2. #2
    Administrator Ken Puls's Avatar
    Join Date
    Mar 2011
    Location
    Nanaimo, BC, Canada
    Posts
    2,343
    Articles
    57
    Blog Entries
    14
    Excel Version
    Excel Office 365 Insider
    You've got a null value somewhere in your data. That causes PQ to return null for any calculation that picks up a null.

    One way of dealing with this is to select all the numeric columns and Replace Values, replacing null with 0. Then run your math and it will work.
    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
    Acolyte Bill Szysz's Avatar
    Join Date
    Apr 2016
    Location
    Poznań, Poland Dublin, Ireland
    Posts
    99
    Articles
    0
    Excel Version
    Excel 365
    Alternatively - you can use construction like this below

    = Table.AddColumn(YourPreviousStep, "Sum", each List.Sum(Record.ToList(_)))

    You do not need to change the null values

  4. #4
    Administrator Ken Puls's Avatar
    Join Date
    Mar 2011
    Location
    Nanaimo, BC, Canada
    Posts
    2,343
    Articles
    57
    Blog Entries
    14
    Excel Version
    Excel Office 365 Insider
    Bill, that's a way better solution. Nulls and zeros are, of course, very different things. Data points should be able to be null (meaning empty) so that they don't get picked up in subsequent calculations.

    I only wish there was an easy UI driven way to do that, rather than having to bash out a List.Sum(Record.ToList()) function that uses an _ as a parameter. No user coming to the tool will be able to figure that out.
    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.

  5. #5
    In this instance, 0 has a value (it enumerates to "normal"), so changing the nulls to zero won't really work ... in the above example:


    "= Table.AddColumn(YourPreviousStep, "Sum", each List.Sum(Record.ToList(_)))
    "

    where/how do you reference the columns you want to sum? I don't want to sum all the columns in the table, only certain ones.

  6. #6
    Acolyte Bill Szysz's Avatar
    Join Date
    Apr 2016
    Location
    Poznań, Poland Dublin, Ireland
    Posts
    99
    Articles
    0
    Excel Version
    Excel 365
    Quote Originally Posted by Ken Puls View Post
    No user coming to the tool will be able to figure that out.
    Hi Ken :-)
    I understand your point of view but ... think.
    Are the users know Vlookup function in excel? and IF function? Can they do nested functions?
    Here (in PQ) is the same situation. It is impossible to get all possible combinations of functions from UI ( the same situation in excel). So, if some user want to get POWER of PQ then he has to know M (this is not as hard as it looks like) :-)

    Regards

  7. #7
    Acolyte Bill Szysz's Avatar
    Join Date
    Apr 2016
    Location
    Poznań, Poland Dublin, Ireland
    Posts
    99
    Articles
    0
    Excel Version
    Excel 365
    Hi beagleton,
    Please, attach an example file. I woluld like to see how your data looks like.

  8. #8
    Administrator Ken Puls's Avatar
    Join Date
    Mar 2011
    Location
    Nanaimo, BC, Canada
    Posts
    2,343
    Articles
    57
    Blog Entries
    14
    Excel Version
    Excel Office 365 Insider
    Quote Originally Posted by Bill Szysz View Post
    Are the users know Vlookup function in excel? and IF function? Can they do nested functions?
    Here (in PQ) is the same situation. It is impossible to get all possible combinations of functions from UI ( the same situation in excel).

    True but why shouldn't you be able to select the four/five columns you want (by holding shift or control), then just to to Add Column --> Standard --> Sum to sum across.

    Oh... my... so we don't have Sum. But we do have Add or Multiply. And the code created is:
    Code:
    = Table.AddColumn(#"Changed Type", "Sum", each List.Sum({[Col2], [Col3], [Col4], [Col5]}), Int64.Type)
    So not exactly what you have as the columns were hard coded, but still, pretty close! And it works with the nulls too.
    Attached Files Attached Files
    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.

  9. #9
    Acolyte Bill Szysz's Avatar
    Join Date
    Apr 2016
    Location
    Poznań, Poland Dublin, Ireland
    Posts
    99
    Articles
    0
    Excel Version
    Excel 365
    So, at the end, we can get the sum from UI :-)))

  10. #10
    Thank you both very much. Once again, this forum has solved my problem.

    Bill, unfortunately my data is made up of restricted information so I can't post ... I will see if I can mask some values or make a similar sample file without the restricted info and upload once I leave work.

Posting Permissions

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