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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
tkk
Frequent Visitor

Consolidating 'repeat' rows containing differing data

First off, I apologize for the confusing title, I wasn't sure exactly what to call what I need done but this screenshot and explanation should clear things up. 

 

In the image of my Power Query Editor you'll see that the rows 'Equipment' and 'Object Text' (the columns mentioned are the 1st and 2nd respectively) repeat 4-6 times while all the columns after that are null except for 1 column in each row that contains data specific to the repeated "Equipment' and 'Object Text'. I am trying to consolidate the repeating rows into 1 row that contains all the data specific to each Eq # and removes the nulls by replacing them with the data that should be there. 

 

I want to say I would like to group by the 'Equipment' or 'Object Text' columns but that creates individual tables for each Eq #.

 PowerQueryEditor.jpg

 

 

 

 

1 ACCEPTED SOLUTION
ImkeF
Super User
Super User

Hi @tkk ,
you could:

  1. Check the first 2 columns
  2. Mouse-right-click: Unpivot other columns
  3. Filter out blank values in column "Value"
  4. Check column "Attribute": Pivot - selelect column "Value" as the Values column and in the Advanced options: "Don't aggregate".
let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WSlTSUTIEYhCK1YHwgSgdjQ9WBeInocknweUz4HyYnthYAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Column1 = _t, Column2 = _t, Column3 = _t, Column4 = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Column1", type text}, {"Column2", type text}, {"Column3", type text}, {"Column4", type text}}),
    #"Unpivoted Other Columns" = Table.UnpivotOtherColumns(#"Changed Type", {"Column1"}, "Attribute", "Value"),
    #"Filtered Rows" = Table.SelectRows(#"Unpivoted Other Columns", each ([Value] <> "")),
    #"Pivoted Column" = Table.Pivot(#"Filtered Rows", List.Distinct(#"Filtered Rows"[Attribute]), "Attribute", "Value")
in
    #"Pivoted Column"

 Or check the file attached.

Imke Feldmann (The BIccountant)

If you liked my solution, please give it a thumbs up. And if I did answer your question, please mark this post as a solution. Thanks!

How to integrate M-code into your solution -- How to get your questions answered quickly -- How to provide sample data -- Check out more PBI- learning resources here -- Performance Tipps for M-queries

View solution in original post

2 REPLIES 2
ImkeF
Super User
Super User

Hi @tkk ,
you could:

  1. Check the first 2 columns
  2. Mouse-right-click: Unpivot other columns
  3. Filter out blank values in column "Value"
  4. Check column "Attribute": Pivot - selelect column "Value" as the Values column and in the Advanced options: "Don't aggregate".
let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WSlTSUTIEYhCK1YHwgSgdjQ9WBeInocknweUz4HyYnthYAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Column1 = _t, Column2 = _t, Column3 = _t, Column4 = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Column1", type text}, {"Column2", type text}, {"Column3", type text}, {"Column4", type text}}),
    #"Unpivoted Other Columns" = Table.UnpivotOtherColumns(#"Changed Type", {"Column1"}, "Attribute", "Value"),
    #"Filtered Rows" = Table.SelectRows(#"Unpivoted Other Columns", each ([Value] <> "")),
    #"Pivoted Column" = Table.Pivot(#"Filtered Rows", List.Distinct(#"Filtered Rows"[Attribute]), "Attribute", "Value")
in
    #"Pivoted Column"

 Or check the file attached.

Imke Feldmann (The BIccountant)

If you liked my solution, please give it a thumbs up. And if I did answer your question, please mark this post as a solution. Thanks!

How to integrate M-code into your solution -- How to get your questions answered quickly -- How to provide sample data -- Check out more PBI- learning resources here -- Performance Tipps for M-queries

tkk
Frequent Visitor

Thank you so much! It worked like magic! That was exactly what I was trying to do, you're awesome!

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

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

Top Solution Authors