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

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
leibowjb
Frequent Visitor

Associating Piped Values in Different Columns

Below I have a dataset where in the left column, "Operation Sale Types" I have various sales types that are contained within pipes. If you look at line 9, you can see that there are 2 different operation sale types. In the right column, "Operation Line Cost", is the associated value for each type also contained within pipes. I want to be able to associate value 1 within column A to value 1 within column B, and so on. Any recommendations?

 

 

dataset.JPG

1 ACCEPTED SOLUTION
v-shex-msft
Community Support
Community Support

Hi @leibowjb,

 

You can refer to below steps to expand those mixed columns.

 

Steps:

1. Enter to query editor.

2. Add custom column to transfer these column to table.

#"Added Custom" = Table.AddColumn(#"Changed Type", "Custom", each Table.FromColumns({Text.Split([Type],"|"),Text.Split([Cost],"|")},{"Type","Cost"}))

3.PNG

 

3. Remove origianl type, cost columns.

#"Removed Other Columns" = Table.SelectColumns(#"Added Custom",{"ID", "Custom"})

4.PNG

 

4. Expand table to new row.

5.PNG6.PNG

 

Full query:

let
    Source = Excel.Workbook(File.Contents("C:\Users\xxxx\Desktop\sample.xlsx"), null, true),
    #"Merge Records_Sheet" = Source{[Item="Merge Records",Kind="Sheet"]}[Data],
    #"Promoted Headers" = Table.PromoteHeaders(#"Merge Records_Sheet", [PromoteAllScalars=true]),
    #"Changed Type" = Table.TransformColumnTypes(#"Promoted Headers",{{"ID", Int64.Type}, {"Type", type text}, {"Cost", type text}}),
    #"Added Custom" = Table.AddColumn(#"Changed Type", "Custom", each Table.FromColumns({Text.Split([Type],"|"),Text.Split([Cost],"|")},{"Type","Cost"})),
    #"Removed Other Columns" = Table.SelectColumns(#"Added Custom",{"ID", "Custom"}),
    #"Expanded Custom" = Table.ExpandTableColumn(#"Removed Other Columns", "Custom", {"Type", "Cost"}, {"Type", "Cost"})
in
    #"Expanded Custom"

 

Regards,

Xiaoxin Sheng

Community Support Team _ Xiaoxin
If this post helps, please consider accept as solution to help other members find it more quickly.

View solution in original post

2 REPLIES 2
v-shex-msft
Community Support
Community Support

Hi @leibowjb,

 

You can refer to below steps to expand those mixed columns.

 

Steps:

1. Enter to query editor.

2. Add custom column to transfer these column to table.

#"Added Custom" = Table.AddColumn(#"Changed Type", "Custom", each Table.FromColumns({Text.Split([Type],"|"),Text.Split([Cost],"|")},{"Type","Cost"}))

3.PNG

 

3. Remove origianl type, cost columns.

#"Removed Other Columns" = Table.SelectColumns(#"Added Custom",{"ID", "Custom"})

4.PNG

 

4. Expand table to new row.

5.PNG6.PNG

 

Full query:

let
    Source = Excel.Workbook(File.Contents("C:\Users\xxxx\Desktop\sample.xlsx"), null, true),
    #"Merge Records_Sheet" = Source{[Item="Merge Records",Kind="Sheet"]}[Data],
    #"Promoted Headers" = Table.PromoteHeaders(#"Merge Records_Sheet", [PromoteAllScalars=true]),
    #"Changed Type" = Table.TransformColumnTypes(#"Promoted Headers",{{"ID", Int64.Type}, {"Type", type text}, {"Cost", type text}}),
    #"Added Custom" = Table.AddColumn(#"Changed Type", "Custom", each Table.FromColumns({Text.Split([Type],"|"),Text.Split([Cost],"|")},{"Type","Cost"})),
    #"Removed Other Columns" = Table.SelectColumns(#"Added Custom",{"ID", "Custom"}),
    #"Expanded Custom" = Table.ExpandTableColumn(#"Removed Other Columns", "Custom", {"Type", "Cost"}, {"Type", "Cost"})
in
    #"Expanded Custom"

 

Regards,

Xiaoxin Sheng

Community Support Team _ Xiaoxin
If this post helps, please consider accept as solution to help other members find it more quickly.
Greg_Deckler
Super User
Super User

Seems like you are going to have to do a split on those columns based on your pipe character and then do some sort of pivot or something. Can you post your sample data as something that can be copied easily?


@ 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...

Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

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