cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
Highlighted
kdecolve
New Member

Power Query: How to add a calculated row?

Hello fellow PowerBI people

I would like to add a calculated row in my dataset. I've no idea how to initiate this.

Database contains + 100 000 rows. There's a different row for each quarter. And I would like to add a new line that gives me the best result over the 4 quarters.

I know I can group this column and add a calculated column, but that is no solution for me as I'll have trouble afterwards filtering correctly.

Example (I would like to add the red line):

YearExtra info AExtra info BQuarterAmount
2019AbcZyx180
2019AbcZyx2null
2019AbcZyx350
2019AbcZyx460
2019AbcZyxBest result80


Thanks in advance for your help!

I think this function can help me: https://docs.microsoft.com/en-us/powerquery-m/table-insertrows

Best regards

Koen

1 ACCEPTED SOLUTION

Accepted Solutions
Community Support
Community Support

Re: Power Query: How to add a calculated row?

Hi @kdecolve ,

 

We can use the following steps to meet your requirement:

 

1. group by the table based on the year column, save other as all rows

 

9.jpg

 

2. Create a custom column:

 

Table.InsertRows(
    [QuarterData],
    Table.RowCount([QuarterData]),
    {
        Record.AddField(Record.RemoveFields(Table.Max([QuarterData],"Amount"),"Quarter"),"Quarter","BestResult")
    }
)

 

10.jpg

 

3. expand the custom column exclude the year column

 

11.jpg

 

2. delete the useless column and rename other column:

 

12.jpg

 

All the queries are here: 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjIwtFTSUXJMSgaSUZUVQNIQiC0MlGJ1sMoaATEuOWMgNsWp0wSIzeCyFlhsNcYpC7LV2BSXrDGSm9DlTKBuigUA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [Year = _t, #"Extra info A" = _t, #"Extra info B" = _t, Quarter = _t, Amount = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Year", Int64.Type}, {"Extra info A", type text}, {"Extra info B", type text}, {"Quarter", Int64.Type}, {"Amount", Int64.Type}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"Year"}, {{"QuarterData", each _, type table [Year=number, Extra info A=text, Extra info B=text, Quarter=number, Amount=number]}}),
    #"Added Custom" = Table.AddColumn(#"Grouped Rows", "Custom", each Table.InsertRows(
    [QuarterData],
    Table.RowCount([QuarterData]),
    {
        Record.AddField(Record.RemoveFields(Table.Max([QuarterData],"Amount"),"Quarter"),"Quarter","BestResult")
    }
)),
    #"Expanded Custom" = Table.ExpandTableColumn(#"Added Custom", "Custom", {"Extra info A", "Extra info B", "Quarter", "Amount"}, {"Custom.Extra info A", "Custom.Extra info B", "Custom.Quarter", "Custom.Amount"}),
    #"Removed Columns" = Table.RemoveColumns(#"Expanded Custom",{"QuarterData"}),
    #"Renamed Columns" = Table.RenameColumns(#"Removed Columns",{{"Custom.Extra info A", "Extra info A"}, {"Custom.Extra info B", "Extra info B"}, {"Custom.Quarter", "Quarter"}, {"Custom.Amount", "Amount"}})
in
    #"Renamed Columns"

 


Best regards,

 

Community Support Team _ Dong Li
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

2 REPLIES 2
JirkaZ Resolver III
Resolver III

Re: Power Query: How to add a calculated row?

PowerQuery is a wrong place to do that. You should use measures for that. 

Community Support
Community Support

Re: Power Query: How to add a calculated row?

Hi @kdecolve ,

 

We can use the following steps to meet your requirement:

 

1. group by the table based on the year column, save other as all rows

 

9.jpg

 

2. Create a custom column:

 

Table.InsertRows(
    [QuarterData],
    Table.RowCount([QuarterData]),
    {
        Record.AddField(Record.RemoveFields(Table.Max([QuarterData],"Amount"),"Quarter"),"Quarter","BestResult")
    }
)

 

10.jpg

 

3. expand the custom column exclude the year column

 

11.jpg

 

2. delete the useless column and rename other column:

 

12.jpg

 

All the queries are here: 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjIwtFTSUXJMSgaSUZUVQNIQiC0MlGJ1sMoaATEuOWMgNsWp0wSIzeCyFlhsNcYpC7LV2BSXrDGSm9DlTKBuigUA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [Year = _t, #"Extra info A" = _t, #"Extra info B" = _t, Quarter = _t, Amount = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Year", Int64.Type}, {"Extra info A", type text}, {"Extra info B", type text}, {"Quarter", Int64.Type}, {"Amount", Int64.Type}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"Year"}, {{"QuarterData", each _, type table [Year=number, Extra info A=text, Extra info B=text, Quarter=number, Amount=number]}}),
    #"Added Custom" = Table.AddColumn(#"Grouped Rows", "Custom", each Table.InsertRows(
    [QuarterData],
    Table.RowCount([QuarterData]),
    {
        Record.AddField(Record.RemoveFields(Table.Max([QuarterData],"Amount"),"Quarter"),"Quarter","BestResult")
    }
)),
    #"Expanded Custom" = Table.ExpandTableColumn(#"Added Custom", "Custom", {"Extra info A", "Extra info B", "Quarter", "Amount"}, {"Custom.Extra info A", "Custom.Extra info B", "Custom.Quarter", "Custom.Amount"}),
    #"Removed Columns" = Table.RemoveColumns(#"Expanded Custom",{"QuarterData"}),
    #"Renamed Columns" = Table.RenameColumns(#"Removed Columns",{{"Custom.Extra info A", "Extra info A"}, {"Custom.Extra info B", "Extra info B"}, {"Custom.Quarter", "Quarter"}, {"Custom.Amount", "Amount"}})
in
    #"Renamed Columns"

 


Best regards,

 

Community Support Team _ Dong Li
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

Helpful resources

Announcements
New Ranks Launched March 24th!

New Ranks Launched March 24th!

The time has come: We are finally able to share more details on the brand-new ranks coming to the Power BI Community!

‘Better Together’ Contest Finalists Announced!

‘Better Together’ Contest Finalists Announced!

Congrats to the finalists of our ‘Better Together’-themed T-shirt design contest! Click for the top entries.

Arun 'Triple A' Event Video, Q&A, and Slides

Arun 'Triple A' Event Video, Q&A, and Slides

Missed the Arun 'Triple A' event or want to revisit it? We've got you covered! Check out the video, Q&A, and slides now.

Join THE global Microsoft Power Platform event series.

Join THE global Power Platform event series.

Attend for two days of expert-led learning and innovation on topics like AI and Analytics, powered by Dynamic Communities.

Community Summit North America

Community Summit North America

Innovate, Collaborate, Grow. The top training and networking event across the globe for Microsoft Business Applications

Top Solution Authors
Top Kudoed Authors