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

The ultimate Microsoft Fabric, Power BI, Azure AI & SQL learning event! Join us in Las Vegas from March 26-28, 2024. Use code MSCUST for a $100 discount. Register Now

Reply
jbenedict2
Frequent Visitor

Split Column Into 2 Columns Based on Key Column

Hi!

 

I am trying to manipulate the following table such that for every APP_NUM there is only one row.  Currently, the table is structured such that for every PROGRAM an APP_NUM is assigned, there is one row, resulting in the possibility of there being more than one row per APP_NUM. 

 

Please see the following for the current structure (I've marked the sample rows where there's a repeat of an APP_NUM because there's more than one PROGRAM):

 

jbenedict2_0-1668701036127.png

 

 

I'd like the output to look like this (I've marked the APP_NUM that previously had 2 rows and is now combined into one row):

 

jbenedict2_1-1668701069835.png

 

The result adds a column for Program2.

 

I've tried pivoting and grouping, but am not getting anywhere (probably due to my lack of proficiency in M). 

 

Any help is greatly appreciated!

1 ACCEPTED SOLUTION
Greg_Deckler
Super User
Super User

@jbenedict2 Try this:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WsjSxUNJRMjIwMjI3ADJKUitKDIF0pFKsDlDSyMgUXdYILmtsaoah1xivrAmyyWbosqYQ2VgA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [APP_NUM = _t, TERM = _t, PROGRAM = _t, ACTIVE_FLAG = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"APP_NUM", Int64.Type}, {"TERM", Int64.Type}, {"PROGRAM", type text}, {"ACTIVE_FLAG", type text}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"APP_NUM"}, {{"TERM", each List.Max([TERM]), type nullable number}, {"ACTIVE_FLAG", each List.Max([ACTIVE_FLAG]), type nullable text}, {"PROGRAM", each _, type table [APP_NUM=nullable number, TERM=nullable number, PROGRAM=nullable text, ACTIVE_FLAG=nullable text]}}),
    #"Added Custom" = Table.AddColumn(#"Grouped Rows", "Custom", each Table.ToList(Table.SelectColumns([PROGRAM],"PROGRAM"))),
    #"Extracted Values" = Table.TransformColumns(#"Added Custom", {"Custom", each Text.Combine(List.Transform(_, Text.From), ","), type text}),
    #"Split Column by Delimiter" = Table.SplitColumn(#"Extracted Values", "Custom", Splitter.SplitTextByDelimiter(",", QuoteStyle.Csv), {"Custom.1", "Custom.2"}),
    #"Changed Type1" = Table.TransformColumnTypes(#"Split Column by Delimiter",{{"Custom.1", type text}, {"Custom.2", type text}}),
    #"Removed Columns" = Table.RemoveColumns(#"Changed Type1",{"PROGRAM"})
in
    #"Removed Columns"

@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
Mastering Power BI 2nd Edition

DAX is easy, CALCULATE makes DAX hard...

View solution in original post

2 REPLIES 2
Greg_Deckler
Super User
Super User

@jbenedict2 Try this:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WsjSxUNJRMjIwMjI3ADJKUitKDIF0pFKsDlDSyMgUXdYILmtsaoah1xivrAmyyWbosqYQ2VgA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [APP_NUM = _t, TERM = _t, PROGRAM = _t, ACTIVE_FLAG = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"APP_NUM", Int64.Type}, {"TERM", Int64.Type}, {"PROGRAM", type text}, {"ACTIVE_FLAG", type text}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"APP_NUM"}, {{"TERM", each List.Max([TERM]), type nullable number}, {"ACTIVE_FLAG", each List.Max([ACTIVE_FLAG]), type nullable text}, {"PROGRAM", each _, type table [APP_NUM=nullable number, TERM=nullable number, PROGRAM=nullable text, ACTIVE_FLAG=nullable text]}}),
    #"Added Custom" = Table.AddColumn(#"Grouped Rows", "Custom", each Table.ToList(Table.SelectColumns([PROGRAM],"PROGRAM"))),
    #"Extracted Values" = Table.TransformColumns(#"Added Custom", {"Custom", each Text.Combine(List.Transform(_, Text.From), ","), type text}),
    #"Split Column by Delimiter" = Table.SplitColumn(#"Extracted Values", "Custom", Splitter.SplitTextByDelimiter(",", QuoteStyle.Csv), {"Custom.1", "Custom.2"}),
    #"Changed Type1" = Table.TransformColumnTypes(#"Split Column by Delimiter",{{"Custom.1", type text}, {"Custom.2", type text}}),
    #"Removed Columns" = Table.RemoveColumns(#"Changed Type1",{"PROGRAM"})
in
    #"Removed Columns"

@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
Mastering Power BI 2nd Edition

DAX is easy, CALCULATE makes DAX hard...

@Greg_Deckler  Thank you for the super-fast response! 

 

I was able to merge the code that you provided with my existing code in the Advanced Editor, and it is now working.

 

I really appreciate the help!

 

Jess

Helpful resources

Announcements
Fabric Community Conference

Microsoft Fabric Community Conference

Join us at our first-ever Microsoft Fabric Community Conference, March 26-28, 2024 in Las Vegas with 100+ sessions by community experts and Microsoft engineering.

February 2024 Update Carousel

Power BI Monthly Update - February 2024

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

Fabric Career Hub

Microsoft Fabric Career Hub

Explore career paths and learn resources in Fabric.

Fabric Partner Community

Microsoft Fabric Partner Community

Engage with the Fabric engineering team, hear of product updates, business opportunities, and resources in the Fabric Partner Community.