Calculate Average In Pivot Table

Sloppyjo3

New Member
Joined
Jan 17, 2020
Messages
11
Office Version
  1. 365
Platform
  1. Windows
Hello,

I have a data set that shows the number of items produced and the date they are produced. In a pivot table, I was able to do a total count per day, but what I really want is the average produced per day. Changing the field settings from "count" to "average" doesn't work...how would I get the average produced per day?

Monday
1112​
Tuesday
2157​
Wednesday
1336​
Thursday
1929​
Friday
1660​
Saturday
6​
Grand Total
8200​
 

Excel Facts

What is =ROMAN(40) in Excel?
The Roman numeral for 40 is XL. Bill "MrExcel" Jelen's 40th book was called MrExcel XL.
If you are currently using a count, it doesn't seem that you have anything to actually average (since a count is basically just counting 1 per row).
 
Upvote 0
Right. So what I want to calculate is the average produced per day of the week. The data set is for a full year.
 
Upvote 0
OK. You're going to need Power Pivot (or Power Query) then because you'll need to create a summary of the count for each day of the year and then average those for each day of the week. (a bit like a pivot based off a pivot)
 
Upvote 0
To elaborate a bit, assuming you have a table called Table1 with a field called Date, you could add a measure called Counter that is just:
Excel Formula:
=COUNTROWS([Table1])
which will give you a simple count. You can then create a measure called DailyAverage using a formula like:

Excel Formula:
=AVERAGEX(SUMMARIZE(Table1,[Date],"RowCount",Table1[Counter]),[RowCount])
which essentially does what I described earlier: creates a summary table with the counts for each date, then takes the average of those. If you then have the days of the week in the row area, that measure will give you the average for each date that was a Monday, Tuesday and so on.
 
Upvote 0

Forum statistics

Threads
1,224,155
Messages
6,176,736
Members
452,741
Latest member
Muhammad Nasir Mahmood

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top