cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
Highlighted
Frequent Visitor

Filtering matrix rows based on multiples columns

Hello,

Can anyone help me with a solution to this?
We have built a Matrix report but need to filter rows based on the value of at least two column in a matrix.

 

VendorCorporateEnergyDefence
Supplier 1Z04MZ06M 
Supplier 2Z06M  
Supplier 3 Z06MZ06M
Supplier 4Z09M  
Supplier 5Z09MZ03M 

 

We want to keep only Supplier 1, 3 & 5.

(and the dream could be only keep Supplier 1 & 5 because value are not the same)

Thanks for your help,
Julian.

1 ACCEPTED SOLUTION

Accepted Solutions
Highlighted
Super User IV
Super User IV

Re: Filtering matrix rows based on multiples columns

@JuliCraps First your table needs to be transformed for better design, basically unpivot your table, to unpivot follow these steps:

 

- transform data
- select vendor column
- right-click, unpivot other columns it will add two columns, attribute, and value, rename these as per your requirement

- filter blank values rows (we don't need these)
- close and apply

To visualize,
- matrix visual:
- add vendor on rows,
- add attribute on columns
- add value on values section

Add the following measure:

 

Count Measure = CALCULATE ( DISTINCTCOUNT ( Vendor[Value] ), ALLEXCEPT ( Vendor, Vendor[Vendor] ) )

 

and use this measure as visual level filter on above matrix visual

 

image.png

 

and here is the result

image.png

 

Here is  M script to unpivot, create a blank query and in advanced editor paste the following code:

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WCi4tKMjJTC1SMFTSUYoyMPEFU2YgSkEpVgdJgRGyDIasMVQYqgJMoSgwAYta4tBuipCNMjAGUUqxsQA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [Vendor = _t, Corporate = _t, Energy = _t, Defence = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Vendor", type text}, {"Corporate", type text}, {"Energy", type text}, {"Defence", type text}}),
    #"Unpivoted Other Columns" = Table.UnpivotOtherColumns(#"Changed Type", {"Vendor"}, "Attribute", "Value"),
    #"Filtered Rows" = Table.SelectRows(#"Unpivoted Other Columns", each ([Value] <> "" and [Value] <> " "))
in
    #"Filtered Rows"

 

I would  Kudos if my solution helped. 👉 If you can spend time posting the question, you can also make efforts to give Kudos whoever helped to solve your problem. It is a token of appreciation!

 

 






Did I answer your question? Mark my post as a solution.

Proud to be a Super User! Appreciate your Kudos 🙂
Feel free to email me with any of your BI needs.





View solution in original post

4 REPLIES 4
Highlighted
Super User IV
Super User IV

Re: Filtering matrix rows based on multiples columns

Filter on Energy <> Blank (Visual level)

 

Or have a measure like

Calculate(Sum(Table[Value]),not(isblank(Table[Energy])))



Did I answer your question? Mark my post as a solution! Appreciate your Kudos!!
My Recent Blog -Week is not so Weak Connect on Linkedin

Proud to be a Super User!

Highlighted
Frequent Visitor

Re: Filtering matrix rows based on multiples columns

Hello @amitchandak,
the filter is not based on "Energy" column but for rows with a value in at least 2 columns.

Highlighted
Super User IV
Super User IV

Re: Filtering matrix rows based on multiples columns

@JuliCraps First your table needs to be transformed for better design, basically unpivot your table, to unpivot follow these steps:

 

- transform data
- select vendor column
- right-click, unpivot other columns it will add two columns, attribute, and value, rename these as per your requirement

- filter blank values rows (we don't need these)
- close and apply

To visualize,
- matrix visual:
- add vendor on rows,
- add attribute on columns
- add value on values section

Add the following measure:

 

Count Measure = CALCULATE ( DISTINCTCOUNT ( Vendor[Value] ), ALLEXCEPT ( Vendor, Vendor[Vendor] ) )

 

and use this measure as visual level filter on above matrix visual

 

image.png

 

and here is the result

image.png

 

Here is  M script to unpivot, create a blank query and in advanced editor paste the following code:

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WCi4tKMjJTC1SMFTSUYoyMPEFU2YgSkEpVgdJgRGyDIasMVQYqgJMoSgwAYta4tBuipCNMjAGUUqxsQA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [Vendor = _t, Corporate = _t, Energy = _t, Defence = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Vendor", type text}, {"Corporate", type text}, {"Energy", type text}, {"Defence", type text}}),
    #"Unpivoted Other Columns" = Table.UnpivotOtherColumns(#"Changed Type", {"Vendor"}, "Attribute", "Value"),
    #"Filtered Rows" = Table.SelectRows(#"Unpivoted Other Columns", each ([Value] <> "" and [Value] <> " "))
in
    #"Filtered Rows"

 

I would  Kudos if my solution helped. 👉 If you can spend time posting the question, you can also make efforts to give Kudos whoever helped to solve your problem. It is a token of appreciation!

 

 






Did I answer your question? Mark my post as a solution.

Proud to be a Super User! Appreciate your Kudos 🙂
Feel free to email me with any of your BI needs.





View solution in original post

Highlighted
Frequent Visitor

Re: Filtering matrix rows based on multiples columns

Thanks lot @parry2k , it's perfect 🤗.
(Apologies, my initial source was not build as i explain, i appreciate your recommandation).

Helpful resources

Announcements
August 2020 Community Challenge: Can You Solve These?

August 2020 Community Challenge: Can You Solve These?

We're excited to announce our first cross-community 'Can You Solve These?' challenge!

Community Blog

Community Blog

Visit our Community Blog for articles, guides, and information created by fellow community members.

Upcoming Events

Upcoming Events

Wondering what events you could join or have an event to promote yourself? Check out our Upcoming Events.

Community Summit Australia – Join Online!

Community Summit Australia – Join Online!

Be a part of the leading Microsoft Business Applications digital event, curated for the APAC community.

Top Solution Authors
Top Kudoed Authors