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

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now! Learn more

Reply
Anonymous
Not applicable

Column Filtering containing value

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...

 

Untitled.png

 

Can this be done?

1 ACCEPTED SOLUTION
AlB
Community Champion
Community Champion

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 

SU18_powerbi_badge

View solution in original post

5 REPLIES 5
AlB
Community Champion
Community Champion

@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 

 

SU18_powerbi_badge

 

Anonymous
Not applicable

@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?

Anonymous
Not applicable

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 🙂

amitchandak
Super User
Super User

@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())

Share with Power BI Enthusiasts: Full Power BI Video (20 Hours) YouTube
Microsoft Fabric Series 60+ Videos YouTube
Microsoft Fabric Hindi End to End YouTube
AlB
Community Champion
Community Champion

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 

SU18_powerbi_badge

Helpful resources

Announcements
Power BI DataViz World Championships

Power BI Dataviz World Championships

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now!

December 2025 Power BI Update Carousel

Power BI Monthly Update - December 2025

Check out the December 2025 Power BI Holiday Recap!

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.

Top Solution Authors