Join us at FabCon Atlanta from March 16 - 20, 2026, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.
Register now!The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now! Learn more
Hello,
I have a large table with respondents (teachers) in rows and many columns. One of the columns contains all the subjects that the teacher teaches (mostly separated by commas). There are about 15 subjects in total. And as you can imagine, one teacher can have 1 or several subjects in this column.
Currently, this format is unusable for power bi vizualizations. To solve that, I would like to make 15 whole new columns (one for each subject), so that the cells only contain true/false.
It is not a very pretty solution, but it will let me use the subjects as filters in visuals. (If you have a simpler solution, that would be also great).
So a cell in the Subjects column can look like: "A, C,D ,F"
So for the first subject I would make a column using something like this (in excel):
=COUNTIF(AJ,"*"&"A"&"*")>0
This looks at the single column (AJ) and returns T/F for each row.
It also lets me use wildcard (my values are not perfectly formated) and allows me to see whether this specific teacher has a subject A.
Then I would make a column for each mentioned subject.
That can´t be done in Power bi. I tried several substitutions found here and elswhere (CALCULATE, IF) but always get en arror message.
Any help is much appriciated.
Thank you!
Solved! Go to Solution.
Hi @Anonymous ,
I create rows for each subject instead of separate columns. Then you can display the data using the matrix visual.
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("fY7BasNADER/ZdmzDqVJPsBN7F5SCKQ3k4O8EbZgvYaVtuC/r3ZL6a2XYWA0ejOOvvPgDy8mH6gLragcBP48RtcljLuwwC1vE04cWXcYSgrKWxL/gNG/Wf/1ZNKnObIscMU0F5yppWcLjg1RhAMMHFeH6ek+KdIXi32BLms7vdQ19dFtMWSl988SsJJa3lt0OpjcA1MKBO+0raR5hwsqTigkzbm75hK0ZPoZONQJR5Oz+532X+PxDQ==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [teacher = _t, Age = _t, subjects = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"teacher", type text}, {"Age", Int64.Type}, {"subjects", type text}}),
#"Added Custom" = Table.AddColumn(#"Changed Type", "Split", each Splitter.SplitTextByDelimiter(",")([subjects])),
#"Added Custom1" = Table.AddColumn(#"Added Custom", "CombineList", each List.Distinct( List.Combine(#"Added Custom"[Split]) )),
#"Added Custom2" = Table.AddColumn(#"Added Custom1", "IsContainSubject", each let CurSplit = [Split], CurComList = [CombineList]
in
List.Generate(()=>[x=0,y=List.Contains([Split],List.Single( List.Range([CombineList], 0, 1))),w=1], each [w] <= 15,each [z=[y], x=[x]+1,y=List.Contains(CurSplit, List.Single(List.Range(CurComList, x, 1))),w=[w]+1
],
each [y])),
#"Added Custom3" = Table.AddColumn(#"Added Custom2", "output", each List.Zip({[CombineList],[IsContainSubject]})),
#"Expanded output" = Table.ExpandListColumn(#"Added Custom3", "output"),
#"Extracted Values" = Table.TransformColumns(#"Expanded output", {"output", each Text.Combine(List.Transform(_, Text.From), ","), type text}),
#"Split Column by Delimiter" = Table.SplitColumn(#"Extracted Values", "output", Splitter.SplitTextByDelimiter(",", QuoteStyle.Csv), {"output.1", "output.2"}),
#"Changed Type1" = Table.TransformColumnTypes(#"Split Column by Delimiter",{{"output.1", type text}, {"output.2", type logical}}),
#"Removed Columns" = Table.RemoveColumns(#"Changed Type1",{"subjects", "Split", "CombineList", "IsContainSubject"})
in
#"Removed Columns"
TO
If the problem is still not resolved, please provide detailed error information or the expected result you expect. Let me know immediately, looking forward to your reply.
Best Regards,
Winniz
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Hi @Anonymous ,
If you want to achieve the same output as COUNTIF, please add the following custom columns in power query editor.
= Text.Contains([subjects], "A", Comparer.OrdinalIgnoreCase)= Text.Contains([subjects], "B", Comparer.OrdinalIgnoreCase)= Text.Contains([subjects], "C", Comparer.OrdinalIgnoreCase)......
If the problem is still not resolved, please provide detailed error information or the expected result you expect. Let me know immediately, looking forward to your reply.
Best Regards,
Winniz
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Hi @Anonymous ,
I create rows for each subject instead of separate columns. Then you can display the data using the matrix visual.
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("fY7BasNADER/ZdmzDqVJPsBN7F5SCKQ3k4O8EbZgvYaVtuC/r3ZL6a2XYWA0ejOOvvPgDy8mH6gLragcBP48RtcljLuwwC1vE04cWXcYSgrKWxL/gNG/Wf/1ZNKnObIscMU0F5yppWcLjg1RhAMMHFeH6ek+KdIXi32BLms7vdQ19dFtMWSl988SsJJa3lt0OpjcA1MKBO+0raR5hwsqTigkzbm75hK0ZPoZONQJR5Oz+532X+PxDQ==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [teacher = _t, Age = _t, subjects = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"teacher", type text}, {"Age", Int64.Type}, {"subjects", type text}}),
#"Added Custom" = Table.AddColumn(#"Changed Type", "Split", each Splitter.SplitTextByDelimiter(",")([subjects])),
#"Added Custom1" = Table.AddColumn(#"Added Custom", "CombineList", each List.Distinct( List.Combine(#"Added Custom"[Split]) )),
#"Added Custom2" = Table.AddColumn(#"Added Custom1", "IsContainSubject", each let CurSplit = [Split], CurComList = [CombineList]
in
List.Generate(()=>[x=0,y=List.Contains([Split],List.Single( List.Range([CombineList], 0, 1))),w=1], each [w] <= 15,each [z=[y], x=[x]+1,y=List.Contains(CurSplit, List.Single(List.Range(CurComList, x, 1))),w=[w]+1
],
each [y])),
#"Added Custom3" = Table.AddColumn(#"Added Custom2", "output", each List.Zip({[CombineList],[IsContainSubject]})),
#"Expanded output" = Table.ExpandListColumn(#"Added Custom3", "output"),
#"Extracted Values" = Table.TransformColumns(#"Expanded output", {"output", each Text.Combine(List.Transform(_, Text.From), ","), type text}),
#"Split Column by Delimiter" = Table.SplitColumn(#"Extracted Values", "output", Splitter.SplitTextByDelimiter(",", QuoteStyle.Csv), {"output.1", "output.2"}),
#"Changed Type1" = Table.TransformColumnTypes(#"Split Column by Delimiter",{{"output.1", type text}, {"output.2", type logical}}),
#"Removed Columns" = Table.RemoveColumns(#"Changed Type1",{"subjects", "Split", "CombineList", "IsContainSubject"})
in
#"Removed Columns"
TO
If the problem is still not resolved, please provide detailed error information or the expected result you expect. Let me know immediately, looking forward to your reply.
Best Regards,
Winniz
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
"To solve that, I would like to make 15 whole new columns (one for each subject)"
That will not help much. Instead, unpivot your data into attribute/value pairs.
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 assist you. I cannot use screenshots of your source data.
Please show the expected outcome based on the sample data you provided. Screenshots of the expected outcome are ok.
https://community.powerbi.com/t5/Desktop/How-to-Get-Your-Question-Answered-Quickly/m-p/1447523
The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now!
| User | Count |
|---|---|
| 19 | |
| 10 | |
| 9 | |
| 7 | |
| 6 |