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
Hi Guys,
Wondered if you could help on this one. I have a dataset with items which are sometimes tagged as Blocked. I want to filter my dataset down so I have items that may once have been tagged as Blocked...but to also retain the times they were not blocked.
See below I want to find a way to filter the column to only retain the red section...
Can this be done?
Solved! Go to Solution.
Hi @Anonymous
Please always show your sample data in text-tabular format in addition to (or instead of) the screen captures. A screen cap doesn't allow people to readily copy the data and run a quick test and thus decreases the likelihood of your question being answered. Just use 'Copy table' in Power BI and paste it here. Or, ideally, share the pbix (beware of confidential data).
Place the following M code in a blank query to see the steps based on a simplified source table:
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjQwUNJRMgRipVgdGNcIlWuMyjWBcY0NLQyNLZC1w0VAJjjl5Cdnp6agShjjkoCbaoTqIiNUFxmhusgIyUWxAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [WorkItemId = _t, ChangedDate = _t, TagNames = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"WorkItemId", Int64.Type}, {"ChangedDate", Int64.Type}, {"TagNames", type text}}),
#"Filtered Rows" = Table.SelectRows(#"Changed Type", each List.Contains(Table.SelectRows(#"Changed Type", (inner)=> inner[WorkItemId]=[WorkItemId])[TagNames], "Blocked"))
in
#"Filtered Rows"
You can also create a new calculated table in DAX, although I would recommend the PQ route:
NewTable =
FILTER( Table1,
CALCULATE(COUNT(Table1[TagNames]), Table1[TagNames] = "Blocked", ALLEXCEPT(Table1, Table1[WorkItemId])) > 0
)
Please mark the question solved when done and consider giving a thumbs up if posts are helpful.
Contact me privately for support with any larger-scale BI needs, tutoring, etc.
Cheers
@Anonymous
NewTable2 =
FILTER (
Table1,
CALCULATE (
COUNT ( Table1[TagNames] ),
SEARCH ( "Blocked", Table1[TagNames], 1, 0 ) > 0,
ALLEXCEPT ( Table1, Table1[WorkItemId] )
) > 0
)
Please mark the question solved when done and consider giving a thumbs up if posts are helpful.
Contact me privately for support with any larger-scale BI needs, tutoring, etc.
Cheers
@AlB what would the current DAX need to be (referring to second part of your answer) if I wanted to include any time there was the word "blocked" (for example if someone used the tag 'blocked - data') and for it be case insensitive?
Thanks guys, both of these solutions work - appreciate your help. I also added
"blocked", Comparer.OrdinalIgnoreCase)
To the first response, just as I noticed I missed some with a capital B 🙂
@Anonymous , You can create a new column like this and filter blocked
new column =
var _cnt = countx(filter(Table, [workitemid] = earlier([workitemid]) && [Tagnames] ="Blocked"), [workitemid])+0
return
if(_cnt >0 , "Blocked", Blank())
Hi @Anonymous
Please always show your sample data in text-tabular format in addition to (or instead of) the screen captures. A screen cap doesn't allow people to readily copy the data and run a quick test and thus decreases the likelihood of your question being answered. Just use 'Copy table' in Power BI and paste it here. Or, ideally, share the pbix (beware of confidential data).
Place the following M code in a blank query to see the steps based on a simplified source table:
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjQwUNJRMgRipVgdGNcIlWuMyjWBcY0NLQyNLZC1w0VAJjjl5Cdnp6agShjjkoCbaoTqIiNUFxmhusgIyUWxAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [WorkItemId = _t, ChangedDate = _t, TagNames = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"WorkItemId", Int64.Type}, {"ChangedDate", Int64.Type}, {"TagNames", type text}}),
#"Filtered Rows" = Table.SelectRows(#"Changed Type", each List.Contains(Table.SelectRows(#"Changed Type", (inner)=> inner[WorkItemId]=[WorkItemId])[TagNames], "Blocked"))
in
#"Filtered Rows"
You can also create a new calculated table in DAX, although I would recommend the PQ route:
NewTable =
FILTER( Table1,
CALCULATE(COUNT(Table1[TagNames]), Table1[TagNames] = "Blocked", ALLEXCEPT(Table1, Table1[WorkItemId])) > 0
)
Please mark the question solved when done and consider giving a thumbs up if posts are helpful.
Contact me privately for support with any larger-scale BI needs, tutoring, etc.
Cheers
The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now!
| User | Count |
|---|---|
| 143 | |
| 123 | |
| 100 | |
| 80 | |
| 55 |