The ultimate Microsoft Fabric, Power BI, Azure AI, and SQL learning event: Join us in Stockholm, September 24-27, 2024.
Save €200 with code MSCUST on top of early bird pricing!
Find everything you need to get certified on Fabric—skills challenges, live sessions, exam prep, role guidance, and more. Get started
Hi , I'm new to power bi need assistance in below
Need to to cancat in power query where column is not blank.
Team | Category | Valid | Owner | Append Result |
1 | A | Yes | X | Proj: 1 | Cat: A | Valid: Yes | Team Owner: X |
2 | B | Proj: 2 | Cat: B | ||
3 | No | Y | Proj: 3 |Valid: No | Team Owner: Y | |
4 | C | Z | Proj: 4 | Cat: C |Team Owner: Z |
Solved! Go to Solution.
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 "")
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:
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:
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 "")
Join the community in Stockholm for expert Microsoft Fabric learning including a very exciting keynote from Arun Ulag, Corporate Vice President, Azure Data.
Check out the August 2024 Power BI update to learn about new features.
Learn from experts, get hands-on experience, and win awesome prizes.