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

Earn a 50% discount on the DP-600 certification exam by completing the Fabric 30 Days to Learn It challenge.

Reply
BI_Analyticz
Helper V
Helper V

How to Merge Ignoring the NULL cells

This may be a simple one but I am pretty new to M/DAX. I have a dataset like below. I want to merge the columns but when I do that with a Delimeter or Space or etc., It is giving that character even if the cells are null.

 

I am merging all these columns and the Result is coming as ABC||BCD|EFG|||GHI||

 

I want the output of merge to be ABC|BCD|EFG|GHI ignoring the null cells. 

 

Col 1Col 2Col 3Col 4Col 5Col 6Col 7Col 8Col 9Col 10Col 11
ABC BCD EFG   GHI  
1 ACCEPTED SOLUTION
Fowmy
Super User
Super User

@BI_Analyticz 

You first Merge the selected columns then, go into the codes of the New Column and add the following:

Text.Combine(List.Select(
{[Col 1], [Col 2], [Col 3], [Col 4], [Col 5], [Col 6], [Col 7], [Col 8], [Col 9]},each _<>""), "|")

You paste the below code in a new blank query in the advanced editor and check the step.

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WcnRyVtJRAiInZxcIw9XNHcKAIHcPT6VYnWgQszglrTgFRBcXg0mIgnIgLoIwK5ViYwE=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Col 1" = _t, #"Col 2" = _t, #"Col 3" = _t, #"Col 4" = _t, #"Col 5" = _t, #"Col 6" = _t, #"Col 7" = _t, #"Col 8" = _t, #"Col 9" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Col 1", type text}, {"Col 2", type text}, {"Col 3", type text}, {"Col 4", type text}, {"Col 5", type text}, {"Col 6", type text}, {"Col 7", type text}, {"Col 8", type text}, {"Col 9", type text}}),
    #"Added Custom" = Table.AddColumn(#"Changed Type", "Custom", each  Text.Combine(List.Select(
{[Col 1], [Col 2], [Col 3], [Col 4], [Col 5], [Col 6], [Col 7], [Col 8], [Col 9]},each _<>""), "|"))
in
    #"Added Custom"

 

 

Fowmy_0-1622720393431.png

 


 

Did I answer your question? Mark my post as a solution! and hit thumbs up


Subscribe and learn Power BI from these videos

Website LinkedIn PBI User Group

View solution in original post

3 REPLIES 3
Fowmy
Super User
Super User

@BI_Analyticz 

You first Merge the selected columns then, go into the codes of the New Column and add the following:

Text.Combine(List.Select(
{[Col 1], [Col 2], [Col 3], [Col 4], [Col 5], [Col 6], [Col 7], [Col 8], [Col 9]},each _<>""), "|")

You paste the below code in a new blank query in the advanced editor and check the step.

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WcnRyVtJRAiInZxcIw9XNHcKAIHcPT6VYnWgQszglrTgFRBcXg0mIgnIgLoIwK5ViYwE=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Col 1" = _t, #"Col 2" = _t, #"Col 3" = _t, #"Col 4" = _t, #"Col 5" = _t, #"Col 6" = _t, #"Col 7" = _t, #"Col 8" = _t, #"Col 9" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Col 1", type text}, {"Col 2", type text}, {"Col 3", type text}, {"Col 4", type text}, {"Col 5", type text}, {"Col 6", type text}, {"Col 7", type text}, {"Col 8", type text}, {"Col 9", type text}}),
    #"Added Custom" = Table.AddColumn(#"Changed Type", "Custom", each  Text.Combine(List.Select(
{[Col 1], [Col 2], [Col 3], [Col 4], [Col 5], [Col 6], [Col 7], [Col 8], [Col 9]},each _<>""), "|"))
in
    #"Added Custom"

 

 

Fowmy_0-1622720393431.png

 


 

Did I answer your question? Mark my post as a solution! and hit thumbs up


Subscribe and learn Power BI from these videos

Website LinkedIn PBI User Group

CNENFRNL
Community Champion
Community Champion

https://community.powerbi.com/t5/Desktop/Combine-or-Merge-Columns-if-the-Column-Header-contains-quot...


Thanks to the great efforts by MS engineers to simplify syntax of DAX! Most beginners are SUCCESSFULLY MISLED to think that they could easily master DAX; but it turns out that the intricacy of the most frequently used RANKX() is still way beyond their comprehension!

DAX is simple, but NOT EASY!

No this post is different. I just want to merge columns but excluding null cells. How can I do that. Kindly help @CNENFRNL 

Helpful resources

Announcements
RTI Forums Carousel3

New forum boards available in Real-Time Intelligence.

Ask questions in Eventhouse and KQL, Eventstream, and Reflex.

MayPowerBICarousel

Fabric Monthly Update - May 2024

Check out the May 2024 Fabric update to learn about new features.

LearnSurvey

Fabric certifications survey

Certification feedback opportunity for the community.