[POWER QUERY] Additional column with summing all previous columns expect the first one

jarekjd

New Member
Joined
Jan 5, 2018
Messages
11
Hello Guys,

Pls help to adjust the code. Beginner struggles... :(

Power Query:
let
    Source = Csv.Document(Web.Contents("https://api.llama.fi/simpleChainDataset/Terra?"),[Delimiter=",", Columns=1160, Encoding=1252, QuoteStyle=QuoteStyle.None]),
    #"Transposed Table" = Table.Transpose(Source),
    #"Promoted Headers" = Table.PromoteHeaders(#"Transposed Table", [PromoteAllScalars=true]),
    #"Changed Type1" = Table.TransformColumnTypes(#"Promoted Headers",{{"Total", type number}, {"Terraswap", type number}, {"Protocol", type text}, {"Lido", type number}, {"Mirror", type number}, {"Anchor", type number}, {"Spectrum Protocol", type number}, {"LoTerra", type number}, {"Pylon Protocol", type number}, {"ApolloDAO", type number}, {"Nexus Protocol", type number}, {"Loop Finance", type number}, {"Starterra", type number}, {"Astroport", type number}, {"Stader", type number}}),
    #"Rows Total" = Table.AddColumn(Source, "Sum", each List.Sum(List.Range(Record.ToList(_),2,Table.ColumnCount(Source)-2)))
in
    #"Rows Total"


I'd like to do 2 things:
1) in #"Changed Type1" - dynamically provide type number to all column except the first one (this is date field)
- above code is referencing specific names but the number of columns is dynamic
2) in #"Rows Total" - add new column which is summing all columns except the first one (these are categories of data i dont need - just a sum of it)

As you can see before that i'm promoting headers from the first row so it should be taken into account.

Can you pls help? Appreciate a lot!
 

Excel Facts

Using Function Arguments with nested formulas
If writing INDEX in Func. Arguments, type MATCH(. Use the mouse to click inside MATCH in the formula bar. Dialog switches to MATCH.
I'd do #1 in two steps for simplicity:

Power Query:
    #"Changed Type" = Table.TransformColumnTypes(#"Promoted Headers",{{"Protocol", type text}}),
    #"Changed Type1" = Table.TransformColumnTypes(#"Changed Type", List.Transform(List.RemoveFirstN(Table.ColumnNames(#"Changed Type"), 1), each{_, type number})),

I'm not clear on #2 - isn't there already a Totals column?
 
Upvote 0
It’s working here - I mean the one in the source file, not the one you added.
 
Upvote 0
I mean that this part of code

Power Query:
= Table.AddColumn(Source, "Sum", each List.Sum(List.Range(Record.ToList(_),2,Table.ColumnCount(Source)-2)))

is generating the following error:

Power Query:
Expression.Error: We cannot apply operator - to types Text and Text.
Details:
    Operator=-
    Left=14/11/2020
    Right=14/11/2020

I'm getting also strange output (headers are lost, table unpivoted) and last column "Sum" shows above error.

1641373255464.png
... next columns go on until 1160
1641373723289.png


Before above step the table looks as follows ( i have applied your changes which are working correctly)

1641373580347.png
 
Upvote 0
My point is that, as in your picture, there is already a Total column, so why are you trying to recreate it? Surely that will just double everything?
 
Upvote 0
It's just input data from a website. It's actually not a full total of all the columns so I do need to sum up all of them
 
Upvote 0
Including that total column?
 
Upvote 0
Change that line to:

Power Query:
    #"Rows Total" = Table.AddColumn(#"Changed Type1", "Sum", each List.Sum(List.Range(Record.ToList(_),2,Table.ColumnCount(#"Changed Type1")-2)))
 
Upvote 0
Solution

Forum statistics

Threads
1,224,823
Messages
6,181,182
Members
453,021
Latest member
Mohamed Magdi Tawfiq Emam

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top