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

Pick a Value From Slicer to Update matrix From Multiple Tables

I have a Sales table that looks like this:

SalesPersonIDStateSalesAmount
235235CA$5,000.00
123CA$10,000.00
5156AZ$80,000.00
23626AZ$20,000.00

 

From Sales table, I used SUMMARIZE to create the following StateAvg table that gives me State Average:

StateSalesAmountPerPerson
CA$7,500.00
AZ$50,000.00

 

I want to show the following Matrix just by using SalesPersonID slicer:

SalesPersonIDStateSalesAmountSalesAmountStateAverage
123CA$10,000.00$7,500.00

 

I built a bridge table for State. SalesPersonID is unique for each state. 

 

When I put 2 slicers: 1 for state and 1 for SalesPersonID, and select State=CA and SalesPersonID=123 in each slicer, I get what I want (3rd table above). 

However, when I just select SalesPersonID = 123 in a slicer, I get average for all states. I cannot create a relationship between Sales and StateAvg table directly because StateAvg table doesn't have SalesPersonID. 

 

How do I make it so that I can just select a SalesPersonID using Slicer to get the state average?

 

Thanks,

 

1 ACCEPTED SOLUTION
TomMartens
Super User II
Super User II

Hey @pucities ,

 

I don't think it's necessary to use a table (SUMMARIZE), I created this measure:

Average Sales Amount = 
AVERAGEX(
    'Table1'
    , var _State = 'Table1'[State]
    return
    CALCULATE(
        AVERAGE('Table1'[SalesAmount])
        , ALL('Table1')
        , 'Table1'[State] = _State
    )
)

This allows to create a report like this:

image.png

or this

image.png

Depending on your data model (star-schema or a one-table solution) the DAX has to be adjusted.

 

Hopefully this is what your are looking for.

 

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

View solution in original post

1 REPLY 1
TomMartens
Super User II
Super User II

Hey @pucities ,

 

I don't think it's necessary to use a table (SUMMARIZE), I created this measure:

Average Sales Amount = 
AVERAGEX(
    'Table1'
    , var _State = 'Table1'[State]
    return
    CALCULATE(
        AVERAGE('Table1'[SalesAmount])
        , ALL('Table1')
        , 'Table1'[State] = _State
    )
)

This allows to create a report like this:

image.png

or this

image.png

Depending on your data model (star-schema or a one-table solution) the DAX has to be adjusted.

 

Hopefully this is what your are looking for.

 

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

View solution in original post

Helpful resources

Announcements
PBI User Groups

Welcome to the User Group Public Preview

Check out new user group experience and if you are a leader please create your group!

MBAS on Demand

Microsoft Business Applications Summit sessions

On-demand access to all the great content presented by the product teams and community members! #MSBizAppsSummit #CommunityRocks

Get Ready for Power BI Dev Camp

Power BI Dev Camp - June 24th

Mark your calendars and join us for our next Power BI Dev Camp!

Top Solution Authors
Top Kudoed Authors