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

The ultimate Microsoft Fabric, Power BI, Azure AI & SQL learning event! Join us in Las Vegas from March 26-28, 2024. Use code MSCUST for a $100 discount. Register Now

Reply
danielboi
Helper I
Helper I

Filter table in Power Query based on two columns

Hello guys,

 

trying to figure out what I though is an easy task so I can streamline my queries.

 

I have two colums I want to use to filter

 

Column 1: File name:

  • 2021 Consolidation.xlsm
  • 2021 Unconsolidated.xlsm

Column 2: Financial Statement item:

  • Sales
  • Sales Intercompany
  • Cost
  • Cost Intercompany

 

What I want to do is to remove the lines matching following criteria:

  • Column 1 text contains "unconsolidated"

AND

  • Column 2 contains "Sales Intercompany" or "Cost Intercompany"

 

I already have a solution to achieve that filtering, via a merch, but that seems too excessive for my goals.

 

D

3 REPLIES 3
TomMartens
Super User
Super User

Hey @danielboi ,

 

create a custom column using an if statement in combination with the function Text.Contains (https://docs.microsoft.com/en-us/powerquery-m/text-contains) like so

if
Text.Contains( [Column1] , "A")
and
( 
Text.Contains( [Column2] , "yellow") or Text.Contains( [Column2] , "red")
)
then "omit" else "keep"

Be aware of the brackets.

Then you can use to values to filter the table and remove the column after the filtering.

Hopefully, this provides an idea on how to tackle your challenge.

Regards,
Tom
  



Did I answer your question? Mark my post as a solution, this will help others!

Proud to be a Super User!
I accept Kudos 😉
Hamburg, Germany

Hey @danielboi ,

if you are familiar with M and the Advanced Editor you can use this one:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WclTSUSpKTVGK1YGwK1NzcvLL4dz0otTUPKXYWAA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Column1 = _t, Column2 = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Column1", type text}, {"Column2", type text}}),


    #"onego" = 
    Table.SelectRows (
        #"Changed Type" , (_) => 
    
         ( Text.Contains( [Column1] , "A") and 
( Text.Contains( [Column2] , "yellow") or Text.Contains( [Column2] , "red") ) = false 
)
    )


//     #"Added Custom" = Table.AddColumn(#"Changed Type", "condition", each if Text.Contains( [Column1] , "A") and 
// ( Text.Contains( [Column2] , "yellow") or Text.Contains( [Column2] , "red") 
// ) then "omit" else "keep")
in
    #"onego"


Regards,
Tom



Did I answer your question? Mark my post as a solution, this will help others!

Proud to be a Super User!
I accept Kudos 😉
Hamburg, Germany
amitchandak
Super User
Super User

@danielboi , Not very clear.

 

Using filters you can get desired output? what is the issue then?

Helpful resources

Announcements
Fabric Community Conference

Microsoft Fabric Community Conference

Join us at our first-ever Microsoft Fabric Community Conference, March 26-28, 2024 in Las Vegas with 100+ sessions by community experts and Microsoft engineering.

February 2024 Update Carousel

Power BI Monthly Update - February 2024

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

Fabric Career Hub

Microsoft Fabric Career Hub

Explore career paths and learn resources in Fabric.

Fabric Partner Community

Microsoft Fabric Partner Community

Engage with the Fabric engineering team, hear of product updates, business opportunities, and resources in the Fabric Partner Community.