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

To celebrate FabCon Vienna, we are offering 50% off select exams. Ends October 3rd. Request your discount now.

Reply

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
Anonymous
Not applicable

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.

View solution in original post

1 REPLY 1
Anonymous
Not applicable

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.

Helpful resources

Announcements
September Power BI Update Carousel

Power BI Monthly Update - September 2025

Check out the September 2025 Power BI update to learn about new features.

August 2025 community update carousel

Fabric Community Update - August 2025

Find out what's new and trending in the Fabric community.