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

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
Anonymous
Not applicable

Average Calculations

Hi

 

I need to calculate an average hours spent with customers on a monthly basis per program. What I am trying to determine is whether the average time spent with a customer is going up or down on a monthly basis. Data extract is similar to last table below. Firstly I need to filter our indirect items and then have an average per month (the average in this example does not make a lot of sense as it is from a very limited data range).  The data consolidates as:

 Hours
ClientJunJulAugGrand Total
12.5 24.5
222.526.5
32 4.56.5
40.52.252.55.25
51.75225.75
6  66
7  22
Grand Total8.756.752136.5

 

Based on this the averages should read (note number of customers takes into account those that may have been counted in prior months as their total hours have been carried forward).

 Hours - Running TotalNo of customersAverage Hours
Jun-198.7551.75
Jul-1915.553.10
Aug-1936.575.21
DateItemTotal HoursProgramCustomer ID
11/06/2019Direct0.5X1
25/06/2019Direct1X1
25/06/2019Direct1X1
9/08/2019Indirect0.5X1
9/08/2019Direct1X1
9/08/2019Direct1X1
5/06/2019Direct1Y2
5/06/2019Direct1Y2
31/07/2019Direct0.5Y2
31/07/2019Direct1Y2
31/07/2019Direct1Y2
28/08/2019Direct0.5Y2
28/08/2019Direct0.5Y2
28/08/2019Direct0.5Y2
28/08/2019Direct0.5Y2
19/06/2019Direct1X3
19/06/2019Direct1X3
1/08/2019Direct1X3
1/08/2019Direct1X3
15/08/2019Direct0.5X3
16/08/2019Indirect0.5X3
21/08/2019Direct0.5X3
21/08/2019Direct0.5X3
21/08/2019Direct0.5X3
21/08/2019Direct0.5X3
18/06/2019Direct0.5Y4
3/07/2019Direct0.25Y4
10/07/2019Direct1Y4
10/07/2019Direct1Y4
9/08/2019Direct1.5Y4
9/08/2019Direct1Y4
5/06/2019Direct0.5X5
5/06/2019Direct0.5X5
12/06/2019Direct0.5X5
13/06/2019Direct0.25X5
3/07/2019Direct0.5X5
3/07/2019Direct0.5X5
3/07/2019Direct1X5
22/07/2019Indirect0.5X5
22/08/2019Direct0.5X5
22/08/2019Direct1X5
22/08/2019Indirect1X5
22/08/2019Direct0.5X5
25/08/2019Direct4X6
31/08/2019Direct2X7
15/08/2019Direct2X6

 

Thanks 

Kate

1 ACCEPTED SOLUTION
Anonymous
Not applicable

Thanks, that has worked well other than I have ran into an issue. I need to be able to filter by program and get the average hours on the program. I have tried to do this with a slicer. It changes everything bar the cumulative count of clients, which then impacts the average hours. What can I put in the measure to be able to take into account of this?

 

For example Customers 1-4 maybe in Program A and 5-7 maybe in Program B and so on.

 

Thanks

View solution in original post

10 REPLIES 10
Nathaniel_C
Super User
Super User

Hi @Anonymous ,

 

Why don't you mark this as solved so that others may find it. You could then repost your latest question as a new question.  I will probably be off line for a couple of days.  This gives others a chance to jump in answer. If you decide not to, I will look at this when I get back on line.

 

If this solves your issues, please mark it as the solution, so that others can find it easily. Kudos are nice too.
Nathaniel





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

Proud to be a Super User!




Hi @Anonymous ,

 

We had to add a filter for aver[Program] changing the ALL() to  ALLEXCEPT(). Here is the updated PBIX.  Average
Let me know if you have any questions.

If this solves your issues, please mark it as the solution, so that others can find it easily. Kudos are nice too.
Nathaniel

 

Total Cumulative hours = 
VAR MaxDate = MAX ( aver[Date] )-- Saves the last visible date
var Hours =
    CALCULATE (
        [Total Hours measure],            -- Computes hours
        aver[Date]<= MaxDate,   -- Where date is before the last visible date
        ALLEXCEPT(  aver,aver[Program] )               -- Removes any other filters from Date allexcept aver[Program]

   )
return Hours

-------------------------------------
Cumulative Count of Customers = 

VAR MaxDate = MAX ( aver[Date] )-- Saves the last visible date
var Counter =
    CALCULATE (
        [Count of customers],            -- Computes customers
        aver[Date]<= MaxDate,   -- Where date is before the last visible date
        ALLEXCEPT( aver,aver[Program] )              -- Removes any other filters from Date allexcept aver([Program]

   )
return Counter




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

Proud to be a Super User!




Nathaniel_C
Super User
Super User

Hi @Anonymous ,

So is this the table you would like to produce? Below you will find the measures.

Let me know if you have any questions.

 

If this solves your issues, please mark it as the solution, so that others can find it easily. Kudos are nice too.
Nathaniel

 

 

 

Average 2.PNG

 

Count of customers = Countrows(DISTINCT(aver[Customer ID]))
Total Hours measure = SUM(aver[Total Hours])
Average Hours per Customer = DIVIDE([Total Hours measure],[Count of customers])




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

Proud to be a Super User!




Anonymous
Not applicable

Hi Nathaniel

 

Thanks for your solution, that has worked. What I need to do next is on a monthly basis get the running average. So for example, June is as per the table. July and August would like below:

 

Total Cumulative Hours

Customer Count

Average Hrs

July

15.5

5 (this includes the 2 in June which were not in July

=15.5/5=3.1

August

36.5

7

=36.5/7=5.21

 

I am easily able to calculate the cumulative hours and average hrs, what I am having issues with is the customer count as I need to take into consideration if the customer has already been a prior customer even if there has been no activity in the current month. In essence what I am trying to do is get the total row as cumulative columns.

@Anonymous ,

Thank you, that makes sense! One thought springs to mind is what about customers who leave the practice?

 

Let me know if you have any questions.

 

If this solves your issues, please mark it as the solution, so that others can find it easily. Kudos are nice too.
Nathaniel

 

Cumulative Count of Customers = 
VAR MaxDate = MAX ( aver[Date] )-- Saves the last visible date
var Counter =
    CALCULATE (
        [Count of customers],            -- Computes customers
        aver[Date]<= MaxDate,   -- Where date is before the last visible date
        ALL ( aver )               -- Removes any other filters from Date

   )
return Counter

Total Cumulative hours = 
VAR MaxDate = MAX ( aver[Date] )-- Saves the last visible date
var Hours =
    CALCULATE (
        [Total Hours measure],            -- Computes hours
        aver[Date]<= MaxDate,   -- Where date is before the last visible date
        ALL ( aver )               -- Removes any other filters from Date

   )
return Hours

These two are almost the same, and finally...

Total Average Hours = Divide([Total Cumulative hours],[Cumulative Count of Customers])

 

 

Cumulative Count average.PNG

 





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

Proud to be a Super User!




Anonymous
Not applicable

Hi Nathaniel

 

How do I get the aver[Date]? Once I type the ( after Max it wants to pick up a field from the table, if I type aver in prior I cannot pick up the date field.

 

Thanks

Kate

Hi @Anonymous ,

aver is my table name. Here is my pbix. aver

 

Let me know if you have more questions, 

 

If this solves your issues, please mark it as the solution, so that others can find it easily. Kudos are nice too.
Nathaniel





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

Proud to be a Super User!




Anonymous
Not applicable

Thanks, that has worked well other than I have ran into an issue. I need to be able to filter by program and get the average hours on the program. I have tried to do this with a slicer. It changes everything bar the cumulative count of clients, which then impacts the average hours. What can I put in the measure to be able to take into account of this?

 

For example Customers 1-4 maybe in Program A and 5-7 maybe in Program B and so on.

 

Thanks

Nathaniel_C
Super User
Super User

Average.PNG

Hi @Anonymous ,

Ran into a little trouble with the dates as you can see, but the totals are correct in the right column. Will try to straighten out the dates.

 

Nathaniel





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

Proud to be a Super User!




Hi @Anonymous 

 

The dates are good.  Not sure what you are trying to do next.

 

If this solves your issues, please mark it as the solution, so that others can find it easily. Kudos are nice too.
Nathaniel

Average 1.PNG





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

Proud to be a Super User!




Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

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