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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
baneworth
Helper II
Helper II

Issue with Matrix and AVG calulcation

Hello,

 

I have a Report with a flaw where modules are counted daily (MO-FR) and then the monthly AVG is then used for Utilization Calculcation (%).

 

If you look at the screenshot below, you can see that the weekdays with no module do not show 0 (added red 0's) and therefore the AVG calculation only uses days with modules and doesnt take 0 into account which results into much higher AVG.

      - please ignore the "Bay Utilization" Matrix

 

0 count.png

 

I am actually overwhelmed and can not figure out how to do that. (applying it both for daily count and monthly AVG)

 

If someone could take a look at the pbix.file and give me a direction that would be amazing and i would very grateful.

- it has calculated table with index to count daily modules

 

pbix.file 

 

Best regards

Mat

1 ACCEPTED SOLUTION

Hi  @baneworth ,

 

Create a measure as below:

Measure 2 = 
var _dates=CALCULATETABLE(VALUES('Date'[Date]),FILTER(ALL('Date'),MONTH('Date'[Date])=MONTH(MAX('Date'[Date]))&&YEAR('Date'[Date])=YEAR(MAX('Date'[Date]))&&'Date'[IsWeekday]=TRUE()))
var _days=CALCULATE(COUNTROWS(_dates),FILTER(_dates,MONTH('Date'[Date])=MONTH(MAX('Date'[Date]))&&YEAR('Date'[Date])=YEAR(MAX('Date'[Date]))))
var _number=CALCULATE(COUNT('Calculated Table'[Index]),FILTER(ALL('Calculated Table'),'Calculated Table'[Group]=MAX('Calculated Table'[Group])&&'Calculated Table'[Date] in _dates))
Return
DIVIDE(_number,_days)+0

And you will see:

v-kelly-msft_0-1616579677811.png

For the related .pbix file,pls see attached.

 

Best Regards,
Kelly

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

 

View solution in original post

6 REPLIES 6
Ashish_Mathur
Super User
Super User

Hi,

Why have you created a calculated table?  Why not drag fields from individual tables?  You may have to rebuild some relationships but i think that will be a better approach.


Regards,
Ashish Mathur
http://www.ashishmathur.com
https://www.linkedin.com/in/excelenthusiasts/
Angith_Nair
Helper V
Helper V

Hi @baneworth ,

Hope you are doing good.

I have looked into your pbix file. Try to create measure instead of plotting direct column (Count of Index) into values.

 

 

test =
IF (
    COUNT ( 'Calculated Table'[Index] ) > 0,
    COUNT ( 'Calculated Table'[Index] ),
    0
)

 

 

 

Angith_Nair_0-1616397702314.png

If this helps then please mark this as solution so that others can refer to it as well.

Hey @Angith_Nair 

 

That worked perfect!

But how would i use this measure to get the AVG for month?

 

Current AVG Formula:

avg formula.png

 

Sorry if this might seem obvious.

 

BR

@baneworth 

You can use the following measure...

 

 

 

Average test module =
VAR AverageValue =
    AVERAGEX (
        FILTER ( 'Date', 'Date'[IsWeekday] = TRUE () ),
        CALCULATE ( DISTINCTCOUNT ( 'Calculated Table'[Index] ) )
    )
VAR SelectedGroup =
    SELECTEDVALUE ( 'Calculated Table'[Group] )
RETURN
    IF ( ISBLANK ( SelectedGroup ) && ISBLANK ( AverageValue ), 0, AverageValue )

 

 

Angith_Nair_0-1616401464535.png

 

 

If this helps then please mark it as a solution.

Dear @Angith_Nair 

 

Unfortunately the AVG values for Jan Feb & Mar did not change throughout the group names.

Sorry if i did not express myself clear enough, i would need to take the days without modules as "0" into the AVG calculcation.

 

example:

current: which would give me AVG of 7

MO   TU   WE   TH   FR

  6      7              7     8

 

needed for AVG calc: which would give me AVG of 5.6

MO   TU   WE   TH   FR

  6      7      0      7     8

 

Creating the monthly AVG including the 0 days would be needed.

 

BR

Appreciate your time!

Hi  @baneworth ,

 

Create a measure as below:

Measure 2 = 
var _dates=CALCULATETABLE(VALUES('Date'[Date]),FILTER(ALL('Date'),MONTH('Date'[Date])=MONTH(MAX('Date'[Date]))&&YEAR('Date'[Date])=YEAR(MAX('Date'[Date]))&&'Date'[IsWeekday]=TRUE()))
var _days=CALCULATE(COUNTROWS(_dates),FILTER(_dates,MONTH('Date'[Date])=MONTH(MAX('Date'[Date]))&&YEAR('Date'[Date])=YEAR(MAX('Date'[Date]))))
var _number=CALCULATE(COUNT('Calculated Table'[Index]),FILTER(ALL('Calculated Table'),'Calculated Table'[Group]=MAX('Calculated Table'[Group])&&'Calculated Table'[Date] in _dates))
Return
DIVIDE(_number,_days)+0

And you will see:

v-kelly-msft_0-1616579677811.png

For the related .pbix file,pls see attached.

 

Best Regards,
Kelly

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

 

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

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

April Fabric Community Update

Fabric Community Update - April 2024

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