Average price depending on the day of the week

Patrick69

New Member
Joined
Oct 13, 2010
Messages
9
Hi All,
Long time reader but first time poster...
I have been searching everywhere for a simple solution to get the average fuel cost depending on which day of the week it is. In other word, how much does fuel cost on Mondays, Tuesdays, etc.
This is my unsuccessful attempt:
=SUMIF(A1:A100,"Monday", B1:B100)/COUNTIF(A1:A100,"Monday")
Where column A has dates and B has the prices I paid per gallon on that day.
I also tried using a 3rd column with just the day of the week (using =A1 and formating to return the day only) but no luck. #DIV/0! Using just SUMIF doesn't work either.
My problem I think is the day...
I am using Excel 2003.
Many thanks for all the help you have already given me,
Patrick
 

Excel Facts

How to show all formulas in Excel?
Press Ctrl+` to show all formulas. Press it again to toggle back to numbers. The grave accent is often under the tilde on US keyboards.
Put this in column C to get the day of the week from the dates in column A

=TEXT(A1, "dddd")

Then use this to Average the Mondays

=SUMIF(C1:C100,"Monday", B1:B100)/COUNTIF(C1:C100,"Monday")


This works as well....
C1
=Weekday(A1)

=SUMIF(C1:C100, 2, B1:B100)/COUNTIF(C1:C100, 2)

Day of the week, with numbers 1 (Sunday) through 7 (Saturday)
 
Last edited:
Upvote 0
Welcome to the MrExcel board!

You could also try these. Each is an array formula so should be confirmed with Ctrl+Shift+Enter, not just Enter. If confirmed correctly, Excel will insert {} around the formula.

=AVERAGE(IF(WEEKDAY(A1:A100)=2,B1:B100))

=AVERAGE(IF(TEXT(A1:A100,"ddd")="Mon",B1:B100))
 
Upvote 0
Peter SSs, I can't make this solution work???
Will it work with Excel 2003?
Excel is not placing the {} and the result is #VALUE!
My A column is formatted to show 19-Aug-2010. Would that make a difference?
Thanks,
Patrick
 
Upvote 0
Mmmmm. Just done it on a new sheet and it works fine... It fails because some days I did not record the date and have placed "???" in the cell. I know there is a way to disregard cells. I will try to find out how. The formula might get ugly though.
Patrick.
 
Upvote 0
This array formula will ignore the cells with ??? or any other text

=AVERAGE(IF(ISERROR(WEEKDAY(A1:A100)),"",IF(WEEKDAY(A1:A100)=2,B1:B100,"")))

Again, this is an array formula. So enter it with Ctrl+Shift+Enter
 
Upvote 0
Here is my final solution:
Column A is formatted as ddd, dd mmm yyyy
No need for a separate day of the week column
=AVERAGE(IF(TEXT(A1:A100,"ddd")="Mon",B1:B100)) is used
And a blank or any other text cell like my ??? are automatically ignored.
Et voilà! A very big thanks to both of you.
Patrick
 
Upvote 0
Here is my final solution:
Column A is formatted as ddd, dd mmm yyyy
No need for a separate day of the week column
=AVERAGE(IF(TEXT(A1:A100,"ddd")="Mon",B1:B100))
Yep, that was suggested back in post #3. :)

Note though that formatting column A as "ddd, dd mmm yyyy" is not necessary for the formula to work. Column A just needs to be Dates.
 
Upvote 0
Interesting! I had assumed (should never do that) that the actual text needed to be present. So following that principal, I assume (will verify as you should never...) that =AVERAGE(IF(WEEKDAY(A1:A100)=2,B1:B100)) would also work as is? But I do prefer your 2nd suggestion as it does not have the risk of getting the wrong day. (Intuitively for me, 1 is Monday).

I need to read about array formulas. I have a feeling that I experimented before unsuccessfully possibly because I had no idea about this array formula thing. Should I be able to see the {}? And if yes, where? Although all is working I do not see them?

Regards, Patrick
 
Upvote 0

Forum statistics

Threads
1,213,536
Messages
6,114,215
Members
448,554
Latest member
Gleisner2

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