cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
ALEX2011ALfer_
Helper I
Helper I

Calculate The mean and std based on tow columns from different tables

Hi EVERYONE 

 

I have many tables, what i want is calculate the avg and std for the [Value] 

based on company and State. 

 

i want to see the avg for all company based on the State. 

let assume that texas state has three company and the [value] fro each company in Texsas are 22,33,55

the avg should be 36.66

same for the std. 

 

i want to disply my visual as Matrix 

 

where the row is Cagtory and the Column is the State

and the value is for avg. 

 

and another matrix for std.

 

here is the power bi file to unnderstand what I'm saying.  Thanks

 

Power bi File  

1 ACCEPTED SOLUTION
yingyinr
Community Support
Community Support

Hi @ALEX2011ALfer_ ,

I updated your sample pbix file(see attachment), please check whether that is what you want. You can create the measures as below to get it:

Measure = 
VAR _selcat =
    SELECTEDVALUE ( 'Dimcagtory'[cagtory id ] )
VAR _selstate =
    SELECTEDVALUE ( Dimstate[state id] )
VAR _citylist =
    CALCULATETABLE (
        VALUES ( 'Dimstate'[cityid] ),
        FILTER ( 'Dimstate', 'Dimstate'[state id] = _selstate )
    )
VAR _cmplist =
    CALCULATETABLE (
        VALUES ( 'Dim Company'[company id] ),
        FILTER ( 'Dim Company', 'Dim Company'[cityid] IN _citylist )
    )
VAR _count =
    CALCULATE (
        DISTINCTCOUNT ( 'Fact Product'[Company Id] ),
        FILTER (
            'Fact Product',
            'Fact Product'[Cagtory id] = _selcat
                && 'Fact Product'[Company Id] IN _cmplist
        )
    )
RETURN
    DIVIDE ( [Value], _count, 0 )
Avg = 
SUMX (
    VALUES ( 'Dimstate'[State name] ),
    SUMX ( VALUES ( 'Dimcagtory'[cagtroy name] ), [Measure] )
)

yingyinr_0-1648105291748.png

By the way, does the std you mentioned refer to standard deviation? If so, you can refer to the link below to implement it.

Community Support Team _ Rena
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

1 REPLY 1
yingyinr
Community Support
Community Support

Hi @ALEX2011ALfer_ ,

I updated your sample pbix file(see attachment), please check whether that is what you want. You can create the measures as below to get it:

Measure = 
VAR _selcat =
    SELECTEDVALUE ( 'Dimcagtory'[cagtory id ] )
VAR _selstate =
    SELECTEDVALUE ( Dimstate[state id] )
VAR _citylist =
    CALCULATETABLE (
        VALUES ( 'Dimstate'[cityid] ),
        FILTER ( 'Dimstate', 'Dimstate'[state id] = _selstate )
    )
VAR _cmplist =
    CALCULATETABLE (
        VALUES ( 'Dim Company'[company id] ),
        FILTER ( 'Dim Company', 'Dim Company'[cityid] IN _citylist )
    )
VAR _count =
    CALCULATE (
        DISTINCTCOUNT ( 'Fact Product'[Company Id] ),
        FILTER (
            'Fact Product',
            'Fact Product'[Cagtory id] = _selcat
                && 'Fact Product'[Company Id] IN _cmplist
        )
    )
RETURN
    DIVIDE ( [Value], _count, 0 )
Avg = 
SUMX (
    VALUES ( 'Dimstate'[State name] ),
    SUMX ( VALUES ( 'Dimcagtory'[cagtroy name] ), [Measure] )
)

yingyinr_0-1648105291748.png

By the way, does the std you mentioned refer to standard deviation? If so, you can refer to the link below to implement it.

Community Support Team _ Rena
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Helpful resources

Announcements
September Update

Check it Out!

Click here to learn more about the September 2022 updates!

Power BI Show episode 9

The Power BI Community Show

Watch the playback when Priya Sathy and Charles Webb discuss Datamarts! Kelly also shares Power BI Community updates.

Power BI Dev Camp Session 26

New Date - Check it Out!

Mark your calendars and join us on Thursday, October 6 at 11a PDT for a great session with Ted Pattison!

Top Solution Authors
Top Kudoed Authors