Power BI is turning 10, and we’re marking the occasion with a special community challenge. Use your creativity to tell a story, uncover trends, or highlight something unexpected.
Get startedJoin us for an expert-led overview of the tools and concepts you'll need to become a Certified Power BI Data Analyst and pass exam PL-300. Register now.
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()
Is there any way with DAX or in PowerQuery to achieve this?
Solved! Go to 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"
This is the sample data, columns can be more in future.
Filename | Col A | Col B | Col C | Col D | Output Col |
Master | 1 | AA | 101 | Master/Col D | |
Master | 2 | BB | SQL | Master/Col C | |
Master | 3 | 102 | Power BI | Master/Col B | |
Source | 4 | 103 | SSIS | Source/Col B | |
Source | 5 | CC | Source/Col C, Col D | ||
Master | 6 | DD | 104 | SSAS | BLANK() |
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"
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.
This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.
Check out the June 2025 Power BI update to learn about new features.
User | Count |
---|---|
8 | |
6 | |
5 | |
2 | |
2 |
User | Count |
---|---|
4 | |
4 | |
3 | |
3 | |
2 |