cancel
Showing results for 
Search instead for 
Did you mean: 
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

Accepted Solutions
Community Support
Community Support

Re: Associating Piped Values in Different Columns

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 Sheng
If this post helps, please consider Accept it as the solution to help the other members find it more quickly
Learning resources: Power BI

View solution in original post

2 REPLIES 2
Super User IV
Super User IV

Re: Associating Piped Values in Different Columns

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?


---------------------------------------

Putting square pegs in round holes since 1972.

I have a NEW book! 
DAX Cookbook from Packt
Over 120 DAX Recipes!
Did I answer your question? Mark my post as a solution!

Proud to be a Datanaut!

Community Support
Community Support

Re: Associating Piped Values in Different Columns

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 Sheng
If this post helps, please consider Accept it as the solution to help the other members find it more quickly
Learning resources: Power BI

View solution in original post

Helpful resources

Announcements
‘Better Together’ T-Shirt Contest – Winner Announced!

‘Better Together’ T-Shirt Contest – Winner Announced!

And the winner is...

Announcing the New Spanish Forum

Announcing the New Spanish Forum

Do you need help in Spanish? Check out our new Spanish community section.

April 2020 Community Highlights

April 2020 Community Highlights

Info on our Super Users, MBAS content and badges, and updates to our support articles. - Read the full Community Highlights.

MBAS Gallery 2020

MBAS Gallery 2020

Watch Microsoft Business Applications Summit sessions on-demand.

Top Solution Authors
Top Kudoed Authors