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

Don't miss out! 2025 Microsoft Fabric Community Conference, March 31 - April 2, Las Vegas, Nevada. Use code MSCUST for a $150 discount. Prices go up February 11th. Register now.

Reply
kinga
Helper I
Helper I

Extracting Data from columns to create other columns

I am having trouble with the below. 

 

We have different levels of approval - 1, 2, and 3.

 

PremiumApprovedBy - are the indiviudals who provided approval

PremiumApprovers are the potential approvers (this provides us with each individual's approval level)

 

What I need to do is assign each record to an approval level and an approver. If PremiumApprovedBy is blank, the approval level is "N/A" and approver is "No Data." If there are multiple individuals in the PremiumApprovedBy column, then the highest level approver and approval level would be assigned. 

 

For example, if PremiumApprovedBy is Alejandro Hernandez;Jaime Romero;Julietta Abril. This record would be assigned to Alejandro Hernandez with an approval level of 3.

 

 

Capture.PNG

1 ACCEPTED SOLUTION
v-yulgu-msft
Microsoft Employee
Microsoft Employee

Hi @kinga,

 

You may achieve such a convertion via Power Query:

let
    Source = Excel.Workbook(File.Contents("C:\Users\xxxx\Desktop\Sample Data (Autosaved).xlsx"), null, true),
    Table1_Sheet = Source{[Item="Table1",Kind="Sheet"]}[Data],
    #"Changed Type" = Table.TransformColumnTypes(Table1_Sheet,{{"Column1", type text}, {"Column2", type text}}),
    #"Promoted Headers" = Table.PromoteHeaders(#"Changed Type", [PromoteAllScalars=true]),
    #"Changed Type1" = Table.TransformColumnTypes(#"Promoted Headers",{{"PremiumApprovedBy", type text}, {"PremiumApprovers", type text}}),
    #"Split Column by Delimiter" = Table.SplitColumn(#"Changed Type1", "PremiumApprovers", Splitter.SplitTextByDelimiter(";", QuoteStyle.Csv), {"PremiumApprovers.1", "PremiumApprovers.2", "PremiumApprovers.3", "PremiumApprovers.4", "PremiumApprovers.5"}),
    #"Changed Type2" = Table.TransformColumnTypes(#"Split Column by Delimiter",{{"PremiumApprovers.1", type text}, {"PremiumApprovers.2", type text}, {"PremiumApprovers.3", type text}, {"PremiumApprovers.4", type text}, {"PremiumApprovers.5", type text}}),
    #"Unpivoted Columns" = Table.UnpivotOtherColumns(#"Changed Type2", {"PremiumApprovedBy"}, "Attribute", "Value"),
    #"Removed Columns" = Table.RemoveColumns(#"Unpivoted Columns",{"Attribute"}),
    #"Added Custom" = Table.AddColumn(#"Removed Columns", "Level", each if [PremiumApprovedBy]<>null then Text.Start([Value],1) else null),
    #"Added Custom1" = Table.AddColumn(#"Added Custom", "IsmultipleIndividuals", each if [PremiumApprovedBy]=null then null else if Text.PositionOf([PremiumApprovedBy],";")>0 then 1 else 0),
    #"Grouped Rows" = Table.Group(#"Added Custom1", {"PremiumApprovedBy"}, {{"Max Level", each List.Max([Level]), type text}, {"All rows", each _, type table}}),
    #"Expanded All rows" = Table.ExpandTableColumn(#"Grouped Rows", "All rows", { "Value", "Level", "IsmultipleIndividuals"}, { "All rows.Value", "All rows.Level", "All rows.IsmultipleIndividuals"}),
    #"Renamed Columns" = Table.RenameColumns(#"Expanded All rows",{{"All rows.Value", "Value"}, {"All rows.Level", "Level"}, {"All rows.IsmultipleIndividuals", "IsmultipleIndividuals"}}),
    #"Added Conditional Column" = Table.AddColumn(#"Renamed Columns", "flag", each if [IsmultipleIndividuals] = 0 then [Level] else if [IsmultipleIndividuals] = 1 then [Max Level] else null),
    #"Added Conditional Column1" = Table.AddColumn(#"Added Conditional Column", "flag2", each if [flag] = [Level] then 1 else 0),
    #"Filtered Rows" = Table.SelectRows(#"Added Conditional Column1", each ([flag2] = 1)),
    #"Removed Other Columns" = Table.SelectColumns(#"Filtered Rows",{"PremiumApprovedBy", "Value"}),
    #"Combine"= Table.Group(#"Removed Other Columns", {"PremiumApprovedBy"}, {{"Column", each Text.Combine([Value], ","), type text}}),
    #"Added Conditional Column2" = Table.AddColumn(Combine, "New PremiumApprover", each if [PremiumApprovedBy] = null then "N/A" else [Column]),
    #"Removed Columns1" = Table.RemoveColumns(#"Added Conditional Column2",{"Column"})
in
    #"Removed Columns1"

I have uploaded the sample .pbix file for your reference. Please check the applied steps in Query Editor mode one by one.

 

Best regards,

Yuliana Gu

Community Support Team _ Yuliana Gu
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

2 REPLIES 2
v-yulgu-msft
Microsoft Employee
Microsoft Employee

Hi @kinga,

 

You may achieve such a convertion via Power Query:

let
    Source = Excel.Workbook(File.Contents("C:\Users\xxxx\Desktop\Sample Data (Autosaved).xlsx"), null, true),
    Table1_Sheet = Source{[Item="Table1",Kind="Sheet"]}[Data],
    #"Changed Type" = Table.TransformColumnTypes(Table1_Sheet,{{"Column1", type text}, {"Column2", type text}}),
    #"Promoted Headers" = Table.PromoteHeaders(#"Changed Type", [PromoteAllScalars=true]),
    #"Changed Type1" = Table.TransformColumnTypes(#"Promoted Headers",{{"PremiumApprovedBy", type text}, {"PremiumApprovers", type text}}),
    #"Split Column by Delimiter" = Table.SplitColumn(#"Changed Type1", "PremiumApprovers", Splitter.SplitTextByDelimiter(";", QuoteStyle.Csv), {"PremiumApprovers.1", "PremiumApprovers.2", "PremiumApprovers.3", "PremiumApprovers.4", "PremiumApprovers.5"}),
    #"Changed Type2" = Table.TransformColumnTypes(#"Split Column by Delimiter",{{"PremiumApprovers.1", type text}, {"PremiumApprovers.2", type text}, {"PremiumApprovers.3", type text}, {"PremiumApprovers.4", type text}, {"PremiumApprovers.5", type text}}),
    #"Unpivoted Columns" = Table.UnpivotOtherColumns(#"Changed Type2", {"PremiumApprovedBy"}, "Attribute", "Value"),
    #"Removed Columns" = Table.RemoveColumns(#"Unpivoted Columns",{"Attribute"}),
    #"Added Custom" = Table.AddColumn(#"Removed Columns", "Level", each if [PremiumApprovedBy]<>null then Text.Start([Value],1) else null),
    #"Added Custom1" = Table.AddColumn(#"Added Custom", "IsmultipleIndividuals", each if [PremiumApprovedBy]=null then null else if Text.PositionOf([PremiumApprovedBy],";")>0 then 1 else 0),
    #"Grouped Rows" = Table.Group(#"Added Custom1", {"PremiumApprovedBy"}, {{"Max Level", each List.Max([Level]), type text}, {"All rows", each _, type table}}),
    #"Expanded All rows" = Table.ExpandTableColumn(#"Grouped Rows", "All rows", { "Value", "Level", "IsmultipleIndividuals"}, { "All rows.Value", "All rows.Level", "All rows.IsmultipleIndividuals"}),
    #"Renamed Columns" = Table.RenameColumns(#"Expanded All rows",{{"All rows.Value", "Value"}, {"All rows.Level", "Level"}, {"All rows.IsmultipleIndividuals", "IsmultipleIndividuals"}}),
    #"Added Conditional Column" = Table.AddColumn(#"Renamed Columns", "flag", each if [IsmultipleIndividuals] = 0 then [Level] else if [IsmultipleIndividuals] = 1 then [Max Level] else null),
    #"Added Conditional Column1" = Table.AddColumn(#"Added Conditional Column", "flag2", each if [flag] = [Level] then 1 else 0),
    #"Filtered Rows" = Table.SelectRows(#"Added Conditional Column1", each ([flag2] = 1)),
    #"Removed Other Columns" = Table.SelectColumns(#"Filtered Rows",{"PremiumApprovedBy", "Value"}),
    #"Combine"= Table.Group(#"Removed Other Columns", {"PremiumApprovedBy"}, {{"Column", each Text.Combine([Value], ","), type text}}),
    #"Added Conditional Column2" = Table.AddColumn(Combine, "New PremiumApprover", each if [PremiumApprovedBy] = null then "N/A" else [Column]),
    #"Removed Columns1" = Table.RemoveColumns(#"Added Conditional Column2",{"Column"})
in
    #"Removed Columns1"

I have uploaded the sample .pbix file for your reference. Please check the applied steps in Query Editor mode one by one.

 

Best regards,

Yuliana Gu

Community Support Team _ Yuliana Gu
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Mond
Helper III
Helper III

Hi, 

For the same example, there are multiple level 3 approvers, so is there a reason, you need Alejandro Hernandez  as the value?

Helpful resources

Announcements
Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Prices go up Feb. 11th.

Feb2025 Sticker Challenge

Join our Community Sticker Challenge 2025

If you love stickers, then you will definitely want to check out our Community Sticker Challenge!

Jan25PBI_Carousel

Power BI Monthly Update - January 2025

Check out the January 2025 Power BI update to learn about new features in Reporting, Modeling, and Data Connectivity.

Jan NL Carousel

Fabric Community Update - January 2025

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