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

Grow your Fabric skills and prepare for the DP-600 certification exam by completing the latest Microsoft Fabric challenge.

Reply
MustafaDaoud10
New Member

Creating New Column

Hello, How can i recreate the Calculation Coumn shown in the image below in Power Query, in a way that it can be done automatically if any new Assessment Unit was added?

Thank you.

xxxx.png

1 ACCEPTED SOLUTION

@MustafaDaoud10 

Hi,

Go to Home then select Advanced Editor. Copy and and past following M code. Then you can get an idea how to do it.

Please note that if there is more than one A2 to one Assesment you will get a wrong answer.

Without seen your dataset its hard to give the best solution.

let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WilDSUXI0BBJGSrE6UK4RkDBEcI2BhAGYGwlTbIngghRbILggxeZgbhRMsRmCC1JsguCCFBsrxcYCAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Assessment = _t, RF = _t, Value = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Assessment", type text}, {"RF", type text}, {"Value", Int64.Type}}),
#"Grouped Rows" = Table.Group(#"Changed Type", {"Assessment"}, {{"Count", each _, type table [Assessment=nullable text, RF=nullable text, Value=nullable number]}}),
#"Duplicated Column" = Table.DuplicateColumn(#"Grouped Rows", "Count", "Count - Copy"),
#"Added Custom" = Table.AddColumn(#"Duplicated Column", "Custom", each Table.SelectRows([#"Count - Copy"], each ([RF] = "A2"))),
#"Expanded Custom" = Table.ExpandTableColumn(#"Added Custom", "Custom", {"Value"}, {"Value"}),
#"Removed Columns" = Table.RemoveColumns(#"Expanded Custom",{"Count - Copy"}),
#"Renamed Columns" = Table.RenameColumns(#"Removed Columns",{{"Value", "RFValue"}}),
#"Expanded Count" = Table.ExpandTableColumn(#"Renamed Columns", "Count", {"RF", "Value"}, {"RF", "Value"}),
#"Changed Type1" = Table.TransformColumnTypes(#"Expanded Count",{{"RFValue", type number}}),
#"Inserted Multiplication" = Table.AddColumn(#"Changed Type1", "Multiplication", each [Value] * [RFValue], type number),
#"Renamed Columns1" = Table.RenameColumns(#"Inserted Multiplication",{{"Multiplication", "Calculation"}})
in
#"Renamed Columns1"

 

Dinesh_Suranga_0-1668331110396.png

Thank you.

View solution in original post

4 REPLIES 4
Dinesh_Suranga
Continued Contributor
Continued Contributor

@MustafaDaoud10 

Hi 

C4 and Value both reffer same cell.

Could you please check the formula?

Thanks

 

Hello Dinesh, the formula is (Value C4 x Value where Assessment Unit = Assessment Unit of C4 AND RF = A2),

Basically for each assessment unit, when the RF = A3 i want to calculate its value times the value of A2 that has the same Assessment unit.

@MustafaDaoud10 

Hi,

Go to Home then select Advanced Editor. Copy and and past following M code. Then you can get an idea how to do it.

Please note that if there is more than one A2 to one Assesment you will get a wrong answer.

Without seen your dataset its hard to give the best solution.

let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WilDSUXI0BBJGSrE6UK4RkDBEcI2BhAGYGwlTbIngghRbILggxeZgbhRMsRmCC1JsguCCFBsrxcYCAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Assessment = _t, RF = _t, Value = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Assessment", type text}, {"RF", type text}, {"Value", Int64.Type}}),
#"Grouped Rows" = Table.Group(#"Changed Type", {"Assessment"}, {{"Count", each _, type table [Assessment=nullable text, RF=nullable text, Value=nullable number]}}),
#"Duplicated Column" = Table.DuplicateColumn(#"Grouped Rows", "Count", "Count - Copy"),
#"Added Custom" = Table.AddColumn(#"Duplicated Column", "Custom", each Table.SelectRows([#"Count - Copy"], each ([RF] = "A2"))),
#"Expanded Custom" = Table.ExpandTableColumn(#"Added Custom", "Custom", {"Value"}, {"Value"}),
#"Removed Columns" = Table.RemoveColumns(#"Expanded Custom",{"Count - Copy"}),
#"Renamed Columns" = Table.RenameColumns(#"Removed Columns",{{"Value", "RFValue"}}),
#"Expanded Count" = Table.ExpandTableColumn(#"Renamed Columns", "Count", {"RF", "Value"}, {"RF", "Value"}),
#"Changed Type1" = Table.TransformColumnTypes(#"Expanded Count",{{"RFValue", type number}}),
#"Inserted Multiplication" = Table.AddColumn(#"Changed Type1", "Multiplication", each [Value] * [RFValue], type number),
#"Renamed Columns1" = Table.RenameColumns(#"Inserted Multiplication",{{"Multiplication", "Calculation"}})
in
#"Renamed Columns1"

 

Dinesh_Suranga_0-1668331110396.png

Thank you.

Thank you so much, Appreciated.

Helpful resources

Announcements
Europe Fabric Conference

Europe’s largest Microsoft Fabric Community Conference

Join the community in Stockholm for expert Microsoft Fabric learning including a very exciting keynote from Arun Ulag, Corporate Vice President, Azure Data.

RTI Forums Carousel3

New forum boards available in Real-Time Intelligence.

Ask questions in Eventhouse and KQL, Eventstream, and Reflex.