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

Create a new column from another table field values

Hello everyone, 

I have a question to create a new table as below.

 

Captured 2020-09-16_002.jpg

I already have 'Table A' in my Power BI and want to get those boolean columns as value in Boolean Type in the new table, and get another column to count the number of true values.

 

Can anyone help me what DAX I need to use to get this new table in Power BI? 

1 ACCEPTED SOLUTION

Accepted Solutions
Highlighted
Community Support
Community Support

Hi @wonygkim ,

 

The calculation logic that @amitchandak given is right. But some details of the formulas need to correct. Please try this:

 

DAX:

new table = 
UNION(
SUMMARIZE('Table', "Boolean Type" , "Boolean A","No of report", COUNTX(FILTER('Table', 'Table'[Boolean A] = "TRUE"), 'Table'[Boolean A])),
SUMMARIZE('Table', "Boolean Type" , "Boolean B","No of report", COUNTX(FILTER('Table', 'Table'[Boolean B] = "TRUE"),'Table'[Boolean B])),
SUMMARIZE('Table', "Boolean Type" , "Boolean C","No of report", COUNTX(FILTER('Table', 'Table'[Boolean C] = "TRUE"), 'Table'[Boolean C])),
SUMMARIZE('Table', "Boolean Type" , "Boolean D","No of report", COUNTX(FILTER('Table', 'Table'[Boolean D] = "TRUE"), 'Table'[Boolean D]))) 

 

M:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WilDSUQoJCnXFTsXqRCtFAjlujj7BrjhpkKoohE50RRCTYgE=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Report = _t, #"Boolean A" = _t, #"Boolean B" = _t, #"Boolean C" = _t, #"Boolean D" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Report", type text}, {"Boolean A", type logical}, {"Boolean B", type logical}, {"Boolean C", type logical}, {"Boolean D", type logical}}),
    #"Unpivoted Columns" = Table.UnpivotOtherColumns(#"Changed Type", {"Report"}, "Attribute", "Value"),
    #"Grouped Rows" = Table.Group(#"Unpivoted Columns", {"Attribute", "Value"}, {{"Count", each Table.RowCount(_), Int64.Type}}),
    #"Filtered Rows" = Table.SelectRows(#"Grouped Rows", each ([Value] = true)),
    #"Removed Columns" = Table.RemoveColumns(#"Filtered Rows",{"Value"})
in
    #"Removed Columns"

2.gif

 

 

Best Regards,
Xue Ding
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

3 REPLIES 3
Highlighted
Super User IV
Super User IV

@wonygkim , Better to unpivot in Power Query, and then Aggregate there.

https://radacad.com/pivot-and-unpivot-with-power-bi
Transpose : https://yodalearning.com/tutorials/power-query-helps-transposing-data/

https://radacad.com/power-bi-aggregation-step-1-create-the-aggregated-table

 

In dax would summarize and union

 

new table =union(
summarize(Table, "Boolean Type" , "No of report", countx(filter(Table, Table[Boolean A] = "True") Table[Boolean A])),
summarize(Table, "Boolean Type" , "No of report", countx(filter(Table, Table[Boolean b] = "True") Table[Boolean B])),
summarize(Table, "Boolean Type" , "No of report", countx(filter(Table, Table[Boolean C] = "True") Table[Boolean C])),
summarize(Table, "Boolean Type" , "No of report", countx(filter(Table, Table[Boolean D] = "True") Table[Boolean D]))) 

 

Change as per need



Did I answer your question? Mark my post as a solution! Appreciate your Kudos!!
Dashboard of My Blogs !! YouTube Channel !! Connect on Linkedin

Proud to be a Super User!

Highlighted
Community Support
Community Support

Hi @wonygkim ,

 

The calculation logic that @amitchandak given is right. But some details of the formulas need to correct. Please try this:

 

DAX:

new table = 
UNION(
SUMMARIZE('Table', "Boolean Type" , "Boolean A","No of report", COUNTX(FILTER('Table', 'Table'[Boolean A] = "TRUE"), 'Table'[Boolean A])),
SUMMARIZE('Table', "Boolean Type" , "Boolean B","No of report", COUNTX(FILTER('Table', 'Table'[Boolean B] = "TRUE"),'Table'[Boolean B])),
SUMMARIZE('Table', "Boolean Type" , "Boolean C","No of report", COUNTX(FILTER('Table', 'Table'[Boolean C] = "TRUE"), 'Table'[Boolean C])),
SUMMARIZE('Table', "Boolean Type" , "Boolean D","No of report", COUNTX(FILTER('Table', 'Table'[Boolean D] = "TRUE"), 'Table'[Boolean D]))) 

 

M:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WilDSUQoJCnXFTsXqRCtFAjlujj7BrjhpkKoohE50RRCTYgE=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Report = _t, #"Boolean A" = _t, #"Boolean B" = _t, #"Boolean C" = _t, #"Boolean D" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Report", type text}, {"Boolean A", type logical}, {"Boolean B", type logical}, {"Boolean C", type logical}, {"Boolean D", type logical}}),
    #"Unpivoted Columns" = Table.UnpivotOtherColumns(#"Changed Type", {"Report"}, "Attribute", "Value"),
    #"Grouped Rows" = Table.Group(#"Unpivoted Columns", {"Attribute", "Value"}, {{"Count", each Table.RowCount(_), Int64.Type}}),
    #"Filtered Rows" = Table.SelectRows(#"Grouped Rows", each ([Value] = true)),
    #"Removed Columns" = Table.RemoveColumns(#"Filtered Rows",{"Value"})
in
    #"Removed Columns"

2.gif

 

 

Best Regards,
Xue Ding
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

Highlighted

thanks a lot!  this helps me understand much better!

Helpful resources

Announcements
Community Conference

Power Platform Community Conference

Check out the on demand sessions that are available now!

Community Conference

Microsoft Power Platform Communities

Check out the Winners!

secondImage

Create an end-to-end data and analytics solution

Learn how Power BI works with the latest Azure data and analytics innovations at the digital event with Microsoft CEO Satya Nadella.

Top Solution Authors
Top Kudoed Authors