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

The Power BI DataViz World Championships are on! With four chances to enter, you could win a spot in the LIVE Grand Finale in Las Vegas. Show off your skills.

Reply
619SK
Helper II
Helper II

Concat Text , Value of column if ot blank

Hi , I'm new to power bi  need assistance in below 

Need to to cancat in power query where column is not blank.

 

 

TeamCategoryValidOwnerAppend Result 
1AYesXProj: 1 | Cat: A | Valid: Yes | Team Owner: X
2B  Proj: 2 | Cat: B
3 NoYProj: 3 |Valid: No | Team Owner: Y
4C ZProj: 4 | Cat: C |Team Owner: Z
2 ACCEPTED SOLUTIONS
Vijay_A_Verma
Super User
Super User

Insert this formula in a custom column

"Proj: " & [Team] & (if [Category] <> "" and [Category] <> null then "| Cat: " & [Category] else "") & (if [Valid] <> "" and [Valid] <> null then "| Valid: " & [Valid] else "") & (if [Owner] <> "" and [Owner] <> null then "| Team Owner: " & [Owner] else "")

View solution in original post

ronrsnfld
Super User
Super User

Here is a method that can be generalized to various column headers. You could even easily add more columns if necessary for your actual data.

 

Since your data seems to have "space" characters for the blanks when pasted into my Power BI table, I "Trimmed" them away. If they are really nulls or empty strings, you may need to edit the code.

 

I created a translation table from column names to "Append Result" which you can also edit if needed.

 

And I used List.Accumulate to get a list of the valid (non-empty) fields to be concatenated.

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlTSUXIE4sjUYiAZoRSrE61kBGQ5AbECGINEjKE8v3yQUrCQCZDlDBWOUoqNBQA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Team = _t, Category = _t, Valid = _t, Owner = _t]),
    #"Col Names" = Table.ColumnNames(Source),
    #"Changed Type" = Table.TransformColumnTypes(Source, List.Transform(#"Col Names", each {_, type nullable text})),
    
    #"Col Name Translation" = List.Zip({#"Col Names", {"Proj","Cat","Valid","Team Owner"}}),

    #"Trim Spaces" = Table.TransformColumns(#"Changed Type", List.Transform(#"Col Names", each {_, Text.Trim})),
    
    #"Add Column" = Table.AddColumn(#"Trim Spaces", "Append Result", (r)=>
        let 
            #"Records to Concat" = 
                Record.RenameFields(
                    Record.SelectFields(r,
                        List.Accumulate(
                        Record.FieldNames(r),
                        {},
                        (s,c) => if Record.Field(r,c) <> "" then s & {c} else s)), 
                    #"Col Name Translation",
                    MissingField.Ignore),
    
            #"Concat" = List.Transform(
                            List.Zip(
                                {Record.FieldNames(#"Records to Concat"), 
                                 Record.FieldValues(#"Records to Concat")}), 
                            each Text.Combine(_,": "))
        in 
            Text.Combine(#"Concat", " | "), type text)
 in
    #"Add Column"

 

Results from your first four columns of data:

ronrsnfld_0-1716208496224.png

 

 

View solution in original post

2 REPLIES 2
ronrsnfld
Super User
Super User

Here is a method that can be generalized to various column headers. You could even easily add more columns if necessary for your actual data.

 

Since your data seems to have "space" characters for the blanks when pasted into my Power BI table, I "Trimmed" them away. If they are really nulls or empty strings, you may need to edit the code.

 

I created a translation table from column names to "Append Result" which you can also edit if needed.

 

And I used List.Accumulate to get a list of the valid (non-empty) fields to be concatenated.

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlTSUXIE4sjUYiAZoRSrE61kBGQ5AbECGINEjKE8v3yQUrCQCZDlDBWOUoqNBQA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Team = _t, Category = _t, Valid = _t, Owner = _t]),
    #"Col Names" = Table.ColumnNames(Source),
    #"Changed Type" = Table.TransformColumnTypes(Source, List.Transform(#"Col Names", each {_, type nullable text})),
    
    #"Col Name Translation" = List.Zip({#"Col Names", {"Proj","Cat","Valid","Team Owner"}}),

    #"Trim Spaces" = Table.TransformColumns(#"Changed Type", List.Transform(#"Col Names", each {_, Text.Trim})),
    
    #"Add Column" = Table.AddColumn(#"Trim Spaces", "Append Result", (r)=>
        let 
            #"Records to Concat" = 
                Record.RenameFields(
                    Record.SelectFields(r,
                        List.Accumulate(
                        Record.FieldNames(r),
                        {},
                        (s,c) => if Record.Field(r,c) <> "" then s & {c} else s)), 
                    #"Col Name Translation",
                    MissingField.Ignore),
    
            #"Concat" = List.Transform(
                            List.Zip(
                                {Record.FieldNames(#"Records to Concat"), 
                                 Record.FieldValues(#"Records to Concat")}), 
                            each Text.Combine(_,": "))
        in 
            Text.Combine(#"Concat", " | "), type text)
 in
    #"Add Column"

 

Results from your first four columns of data:

ronrsnfld_0-1716208496224.png

 

 

Vijay_A_Verma
Super User
Super User

Insert this formula in a custom column

"Proj: " & [Team] & (if [Category] <> "" and [Category] <> null then "| Cat: " & [Category] else "") & (if [Valid] <> "" and [Valid] <> null then "| Valid: " & [Valid] else "") & (if [Owner] <> "" and [Owner] <> null then "| Team Owner: " & [Owner] else "")

Helpful resources

Announcements
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!

Jan NL Carousel

Fabric Community Update - January 2025

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

Top Solution Authors