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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
A123-Chauhan
Employee
Employee

Use Column header in calculated column

Hi All,

I need help with the below requirement :
This is the sample file data I am currently working on. It contains the below columns having some blank values. I need an additional calculated column (Output column) that will contain the values of one column(Filename) with the header name of columns having blank values.

Below are the use cases:

In row 1, Col D is blank , so output is : Master/Col D

In row 5, Col C and Col D are blank, so output is : Master/Col C, Col D

In row 6, there is no blank column, so output is : BLANK()

A123Chauhan_0-1644474100536.png

 

Is there any way with DAX or in PowerQuery to achieve this?

 

1 ACCEPTED SOLUTION

Thank you for the sample data.  Note that it has a lot of extra spaces so the following code may need some adjustments once you cleaned the data up.

 

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45W8k0sLkktUtJRMgRiR0cQwwDEVFCK1UGSNQJiJyewuI5ScKAPqqwxVMLQAKQuIL88tUjByROsJji/tCg5FShqAlcDUh0c7BmMKm8KxM7OUEVotpsBsYsLWLMJWLMjUHMsAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Filename = _t, #"   Col A" = _t, #"   Col B" = _t, #"   Col C" = _t, #"  Col D" = _t]),
    CN =Table.ColumnNames(Source),
    #"Added Custom" = Table.AddColumn(Source, "Output Col",
  (k)=> let l =
  List.Generate(()=>[x=1,y=""], 
      each [x] < List.Count(CN), 
      each [x=[x]+1, y=[y] & (if Record.Field(k,CN{[x]}) > " " then "" else ", " & CN{[x]})],
      each [y] & (if Record.Field(k,CN{[x]}) > " " then "" else ", " & CN{[x]})
  ),
  m = try Record.Field(k,CN{0}) & "/" & Text.Range(l{List.Count(CN)-2},2) otherwise null
  in m
)
in
    #"Added Custom"

 

How to use this code: Create a new Blank Query. Click on "Advanced Editor". Replace the code in the window with the code provided here. Click "Done".

lbendlin_0-1644939728676.png

 

View solution in original post

3 REPLIES 3
A123-Chauhan
Employee
Employee

This is the sample data, columns can be more in future.

 

Filename   Col A   Col B   Col C  Col D      Output Col
Master1AA101 Master/Col D
Master2BB SQLMaster/Col C
Master3 102Power BIMaster/Col B
Source4 103SSISSource/Col B
Source5CC  Source/Col C, Col D
Master6DD104SSASBLANK()

 

Basically, I am looking for a dynamic solution that if any column in the table is blank that Column name has to be spotted in the output column. One shouldn't specifically mention any column name to check if it is blank or not i.e., the isblank operation should be performed row-wise.

 

I hope it helps @lbendlin 

 

Thank you for the sample data.  Note that it has a lot of extra spaces so the following code may need some adjustments once you cleaned the data up.

 

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45W8k0sLkktUtJRMgRiR0cQwwDEVFCK1UGSNQJiJyewuI5ScKAPqqwxVMLQAKQuIL88tUjByROsJji/tCg5FShqAlcDUh0c7BmMKm8KxM7OUEVotpsBsYsLWLMJWLMjUHMsAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Filename = _t, #"   Col A" = _t, #"   Col B" = _t, #"   Col C" = _t, #"  Col D" = _t]),
    CN =Table.ColumnNames(Source),
    #"Added Custom" = Table.AddColumn(Source, "Output Col",
  (k)=> let l =
  List.Generate(()=>[x=1,y=""], 
      each [x] < List.Count(CN), 
      each [x=[x]+1, y=[y] & (if Record.Field(k,CN{[x]}) > " " then "" else ", " & CN{[x]})],
      each [y] & (if Record.Field(k,CN{[x]}) > " " then "" else ", " & CN{[x]})
  ),
  m = try Record.Field(k,CN{0}) & "/" & Text.Range(l{List.Count(CN)-2},2) otherwise null
  in m
)
in
    #"Added Custom"

 

How to use this code: Create a new Blank Query. Click on "Advanced Editor". Replace the code in the window with the code provided here. Click "Done".

lbendlin_0-1644939728676.png

 

lbendlin
Super User
Super User

You cannot do that in DAX, but it is possible to do in Power Query. Please provide sanitized sample data that fully covers your issue. If you paste the data into a table in your post or use one of the file services it will be easier to work with. 

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

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