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
Zarlot531
Helper V
Helper V

Tricky divide by "Distinct Count" problem

So below is a sample dataset to help clarify what I'm trying to do. I want to know how much we spent on, say, the "Dog" vendor divided by ALL distinct jobs, regardless of whether we spent money at the dog vendor for other jobs. 

 

So for ex, the Dog average below would be (200+200+388) / 4 (total distinct jobs, 3561, 7898, 8982, 3893) = 197 dog cost / all jobs. 

 

What Power BI seems to want to to do is give me the average of distinct jobs where and only where we had "Dog" vendor cost. 

 

So it doesn't even consider jobs 8982 or 3893. It instead wants to divide by 2 (3561 and 7898). 

 

I've tried experimenting with different DAX formulas but can't seem to get it right. @

 

Capture3333.JPG

1 ACCEPTED SOLUTION
v-frfei-msft
Community Support
Community Support

Hi @Zarlot531 ,

 

Measure =
VAR ave =
    SUM ( 'Table'[Amount] )
VAR dis =
    CALCULATE ( DISTINCTCOUNT ( 'Table'[Job] ), ALL ( 'Table' ) )
RETURN
    DIVIDE ( ave, dis )

Capture.PNG

Please refer to the pbix as attached.

 

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

View solution in original post

2 REPLIES 2
v-frfei-msft
Community Support
Community Support

Hi @Zarlot531 ,

 

Measure =
VAR ave =
    SUM ( 'Table'[Amount] )
VAR dis =
    CALCULATE ( DISTINCTCOUNT ( 'Table'[Job] ), ALL ( 'Table' ) )
RETURN
    DIVIDE ( ave, dis )

Capture.PNG

Please refer to the pbix as attached.

 

Community Support Team _ Frank
If this post helps, then please consider Accept it as the solution to help the others find it more quickly.
ImkeF
Super User
Super User

Hi @Zarlot531

you have to remove the filter from Vendor like so:

 

Avg across all jobs =
VAR SumVendor =
    SUM ( Table1[Amount] )
VAR NoOfAllJobs =
    CALCULATE ( DISTINCTCOUNT ( Table1[Job] ), ALL ( Table1[Vendor] ) )
RETURN
    DIVIDE ( SumVendor, NoOfAllJobs )

 

Imke Feldmann (The BIccountant)

If you liked my solution, please give it a thumbs up. And if I did answer your question, please mark this post as a solution. Thanks!

How to integrate M-code into your solution -- How to get your questions answered quickly -- How to provide sample data -- Check out more PBI- learning resources here -- Performance Tipps for M-queries

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.