Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Enhance your career with this limited time 50% discount on Fabric and Power BI exams. Ends August 31st. Request your voucher.

Reply
davidz106
Helper III
Helper III

Sum multiple columns

I am trying to sum 3 colums at the time and do that for a total of 300 columns. 

 

#"sum" = Table.AddColumn(#"previous", "sum", each List.Sum({[#"10,0"], [#"20,0"], [#"30,0"]}), type number),
#"sum1" = Table.AddColumn(#"sum", "sum1", each List.Sum({[#"40,0"], [#"50,0"], [#"60,0"]}), type number),
#"sum2" = Table.AddColumn(#"sum1", "sum2", each List.Sum({[#"70,0"], [#"80,0"], [#"90,0"]}), type number)

...

 

Any way to type this in one line?

1 ACCEPTED SOLUTION
Vijay_A_Verma
Super User
Super User

See the working here - Open a blank query - Home - Advanced Editor - Remove everything from there and paste the below code to test (later on when you use the query on your dataset, you will have to change the source appropriately. If you have columns other than these, then delete Changed type step and do a Changed type for complete table from UI again)

Here I have chosen 12 columns to sum, hence in List.Generate, I am choosing [i]<4. For 300 columns, this will be [i]<100

Also, since I don't know the columns in your table, hence I have assumed that there is 1 column before your columns which need to be summed up starts. Hence, I have used r=List.RemoveFirstN(Record.ToList(_),1) which removes first column. If you have many columns before your summable columns start, please change 1 with that number.

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("VZBLDsMwCETv4nUWMcFgL/u9hJX7X6N+RLTqZgQDDANzllvZSvcFogt8X6B9wWGkgMiCOuCiQDTqglbLuc1yJ2z0UG6AMddjGMEB5+g3hvWgGfARCg+6g8SIom2kAjRJD6rpNdY73HF5eGY5yIobjUbWd9JGZJ7rOwoqPw8vSNxZS4Ur0rws9E1SJqrxL+mh8MaO/L0zhsN73/MF7rnevlVbV5wf", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Employe = _t, #"10,0" = _t, #"20,0" = _t, #"30,0" = _t, #"40,0" = _t, #"50,0" = _t, #"60,0" = _t, #"70,0" = _t, #"80,0" = _t, #"90,0" = _t, #"100,0" = _t, #"110,0" = _t, #"120,0" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Employe", type text}, {"10,0", Int64.Type}, {"20,0", Int64.Type}, {"30,0", Int64.Type}, {"40,0", Int64.Type}, {"50,0", Int64.Type}, {"60,0", Int64.Type}, {"70,0", Int64.Type}, {"80,0", Int64.Type}, {"90,0", Int64.Type}, {"100,0", Int64.Type}, {"110,0", Int64.Type}, {"120,0", Int64.Type}}),
    #"Added Custom" = Table.AddColumn(#"Changed Type", "Sum", each List.Generate(()=>[x=List.Sum(List.Range(r,0,3)),i=0,r=List.RemoveFirstN(Record.ToList(_),1)], each [i]<4, each [i=[i]+1, r=[r], x=List.Sum(List.Range([r],i*3,3))], each [x])),
    #"Extracted Values" = Table.TransformColumns(#"Added Custom", {"Sum", each Text.Combine(List.Transform(_, Text.From), ";"), type text}),
    #"Split Column by Delimiter" = Table.SplitColumn(#"Extracted Values", "Sum", Splitter.SplitTextByDelimiter(";", QuoteStyle.Csv), List.Transform({1..List.Max(Table.AddColumn(#"Extracted Values", "Temp", each List.Count(Text.Split([Sum],";")))[Temp])},each "Sum." & Number.ToText(_)))
in
    #"Split Column by Delimiter"

 

View solution in original post

1 REPLY 1
Vijay_A_Verma
Super User
Super User

See the working here - Open a blank query - Home - Advanced Editor - Remove everything from there and paste the below code to test (later on when you use the query on your dataset, you will have to change the source appropriately. If you have columns other than these, then delete Changed type step and do a Changed type for complete table from UI again)

Here I have chosen 12 columns to sum, hence in List.Generate, I am choosing [i]<4. For 300 columns, this will be [i]<100

Also, since I don't know the columns in your table, hence I have assumed that there is 1 column before your columns which need to be summed up starts. Hence, I have used r=List.RemoveFirstN(Record.ToList(_),1) which removes first column. If you have many columns before your summable columns start, please change 1 with that number.

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("VZBLDsMwCETv4nUWMcFgL/u9hJX7X6N+RLTqZgQDDANzllvZSvcFogt8X6B9wWGkgMiCOuCiQDTqglbLuc1yJ2z0UG6AMddjGMEB5+g3hvWgGfARCg+6g8SIom2kAjRJD6rpNdY73HF5eGY5yIobjUbWd9JGZJ7rOwoqPw8vSNxZS4Ur0rws9E1SJqrxL+mh8MaO/L0zhsN73/MF7rnevlVbV5wf", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Employe = _t, #"10,0" = _t, #"20,0" = _t, #"30,0" = _t, #"40,0" = _t, #"50,0" = _t, #"60,0" = _t, #"70,0" = _t, #"80,0" = _t, #"90,0" = _t, #"100,0" = _t, #"110,0" = _t, #"120,0" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Employe", type text}, {"10,0", Int64.Type}, {"20,0", Int64.Type}, {"30,0", Int64.Type}, {"40,0", Int64.Type}, {"50,0", Int64.Type}, {"60,0", Int64.Type}, {"70,0", Int64.Type}, {"80,0", Int64.Type}, {"90,0", Int64.Type}, {"100,0", Int64.Type}, {"110,0", Int64.Type}, {"120,0", Int64.Type}}),
    #"Added Custom" = Table.AddColumn(#"Changed Type", "Sum", each List.Generate(()=>[x=List.Sum(List.Range(r,0,3)),i=0,r=List.RemoveFirstN(Record.ToList(_),1)], each [i]<4, each [i=[i]+1, r=[r], x=List.Sum(List.Range([r],i*3,3))], each [x])),
    #"Extracted Values" = Table.TransformColumns(#"Added Custom", {"Sum", each Text.Combine(List.Transform(_, Text.From), ";"), type text}),
    #"Split Column by Delimiter" = Table.SplitColumn(#"Extracted Values", "Sum", Splitter.SplitTextByDelimiter(";", QuoteStyle.Csv), List.Transform({1..List.Max(Table.AddColumn(#"Extracted Values", "Temp", each List.Count(Text.Split([Sum],";")))[Temp])},each "Sum." & Number.ToText(_)))
in
    #"Split Column by Delimiter"

 

Helpful resources

Announcements
July 2025 community update carousel

Fabric Community Update - July 2025

Find out what's new and trending in the Fabric community.

July PBI25 Carousel

Power BI Monthly Update - July 2025

Check out the July 2025 Power BI update to learn about new features.