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

Find everything you need to get certified on Fabric—skills challenges, live sessions, exam prep, role guidance, and more. Get started

Reply
Ronniemaccagee
Frequent Visitor

Expand Table columns based on row entries - to create a unique identifier

Hi has anyone managed to do the following? - 

 

I have 200 rows, in Column A I have JOB IDs populating, when a new job populates with the same JOB ID id like the row data to join the original row.

 

Is it possible to add say 2 or 4 columns which only populate when the duplicate JOB ID is found?

 

I would then want to delete the row so that only the original row remains in the table

 

Thoughts?

1 ACCEPTED SOLUTION
edhans
Super User
Super User

See the logic in the M code below. Basically this:

  • Groups all data by ID
  • Gets the first record based on the date. If it has duplicate IDs, it gets the first record. If not, it gets the only record.
  • Remove all previous columns
  • Expand the new unique and first record for each ID.

If you need further help, please provide data per the links at the bottom of this post.

 

1) In Power Query, select New Source, then Blank Query
2) On the Home ribbon, select "Advanced Editor" button
3) Remove everything you see, then paste the M code I've given you in that box.
4) Press Done

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("XcjJCQAwCATAXvYteKcZsf82AhIQMs+pgoIQrGxigqaCTdiGT/gfsRETuZET50Vf", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [ID = _t, Date = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"ID", Int64.Type}, {"Date", type date}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"ID"}, {{"All Rows", each _, type table [ID=number, Date=date]}}),
    #"Added Custom" = Table.AddColumn(#"Grouped Rows", "Original Records", each Table.Max([All Rows], "Date")),
    #"Removed Other Columns" = Table.SelectColumns(#"Added Custom",{"Original Records"}),
    #"Expanded Original Records" = Table.ExpandRecordColumn(#"Removed Other Columns", "Original Records", {"ID", "Date"}, {"ID", "Date"})
in
    #"Expanded Original Records"

 

How to get good help fast. Help us help you.
How to Get Your Question Answered Quickly
How to provide sample data in the Power BI Forum



Did I answer your question? Mark my post as a solution!
Did my answers help arrive at a solution? Give it a kudos by clicking the Thumbs Up!

DAX is for Analysis. Power Query is for Data Modeling


Proud to be a Super User!

MCSA: BI Reporting

View solution in original post

1 REPLY 1
edhans
Super User
Super User

See the logic in the M code below. Basically this:

  • Groups all data by ID
  • Gets the first record based on the date. If it has duplicate IDs, it gets the first record. If not, it gets the only record.
  • Remove all previous columns
  • Expand the new unique and first record for each ID.

If you need further help, please provide data per the links at the bottom of this post.

 

1) In Power Query, select New Source, then Blank Query
2) On the Home ribbon, select "Advanced Editor" button
3) Remove everything you see, then paste the M code I've given you in that box.
4) Press Done

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("XcjJCQAwCATAXvYteKcZsf82AhIQMs+pgoIQrGxigqaCTdiGT/gfsRETuZET50Vf", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [ID = _t, Date = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"ID", Int64.Type}, {"Date", type date}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"ID"}, {{"All Rows", each _, type table [ID=number, Date=date]}}),
    #"Added Custom" = Table.AddColumn(#"Grouped Rows", "Original Records", each Table.Max([All Rows], "Date")),
    #"Removed Other Columns" = Table.SelectColumns(#"Added Custom",{"Original Records"}),
    #"Expanded Original Records" = Table.ExpandRecordColumn(#"Removed Other Columns", "Original Records", {"ID", "Date"}, {"ID", "Date"})
in
    #"Expanded Original Records"

 

How to get good help fast. Help us help you.
How to Get Your Question Answered Quickly
How to provide sample data in the Power BI Forum



Did I answer your question? Mark my post as a solution!
Did my answers help arrive at a solution? Give it a kudos by clicking the Thumbs Up!

DAX is for Analysis. Power Query is for Data Modeling


Proud to be a Super User!

MCSA: BI Reporting

Helpful resources

Announcements
Sept PBI Carousel

Power BI Monthly Update - September 2024

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

September Hackathon Carousel

Microsoft Fabric & AI Learning Hackathon

Learn from experts, get hands-on experience, and win awesome prizes.

Sept NL Carousel

Fabric Community Update - September 2024

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

Top Solution Authors