[mso] Re: Excel question

  • From: Thomas Hutchins <hutch99999@xxxxxxxxx>
  • To: mso@xxxxxxxxxxxxx
  • Date: Mon, 23 Nov 2009 10:57:00 -0800 (PST)

Excel 2003 has COUNTIF and SUMIF functions, but not COUNTIFS, AVERAGEIF, 
AVERAGEIFS, or SUMIFS. You could use array formulas, or SUMPRODUCT formulas 
like the following:
 
in A2 (count formula):
=SUMPRODUCT(--(I2:I65000>0),--(I2:I65000<0.0416667),--(Q2:Q65000=W7))
 
in A1 (average formula):
=IF(A2=0,0,SUMPRODUCT(--(I2:I65000>0),--(I2:I65000<0.0416667),--(Q2:Q65000=W7),U2:U65000)/A2)
 
Please note that you can't use whole columns with SUMPRODUCT in Excel 2003.
 
Hope this helps,
 
Hutch
--- On Mon, 11/23/09, John Perrin <jperrin@xxxxxxxxxxxxx> wrote:


From: John Perrin <jperrin@xxxxxxxxxxxxx>
Subject: [mso] Excel question
To: mso@xxxxxxxxxxxxx
Date: Monday, November 23, 2009, 10:52 AM


Good Morning,

I was wondering if anyone happens to know if the "Averageifs" and "Countifs" 
formula functions are available in Office 2003?  If not, what are my 
alternatives to writing formulas to look at multiple columns and do average and 
count functions?  A suggested possible solution was to buy Office 2007, write 
the formulas in that sheet and then "down convert" the formulas to 2003.  Does 
anyone know if this actually works?

I will give an example to help.  I have a sheet with ~40,000 lines of data.  
Columns are:
1. Day of week (formula from a date/time field of when blood was drawn)
2. Time of day (formula from same field in #1)
3. Turn around time (formula from date/time of blood drawn until results 
available to clinician from another captured date/time)

What I would like is an average for #3, given hour of day blood drawn (#2) and 
day of week (#1).  My friend and I have come up with these 2 formulas in Excel 
2007 for average turn around time and counts for # of blood draws for each hour 
of the day for our inpatients:
Average TAT:    =AVERAGEIFS(U:U,I:I,">0",I:I,"<.0416667",Q:Q,"=Fr")  this is 
the formula for midnight to 1:00 AM
Counting:       =COUNTIFS(I:I,">0",I:I,"<=.041667",Q:Q,W7)  where W7 is the 
cell that has "Fr" for Friday, etc...

I had asked a question of this group earlier and was given an answer of using 
conditional array formulas which worked beautifully.  It was noted by the 
person that you cannot use I:I for complex formulas in 2003 but you can in 2007 
so I did modify the formula everywhere there was a colon I entered numbers for 
the cells and it still gives me "?NAME" for an answer.

Formula I used was 
:   =AVERAGEIFS(U2:U60000,I2:I60000,">0",I2:I60000,"<.041667",Q2:Q60000,="Fr")   hoping
 that adding the numbers would solve the problem....it doesn't.

Any help or additional information about 2003, 2007, compatibility, AVERAGEIFS, 
etc...  would be greatly appreciated.  I hope everyone has a great Thanksgiving.

John Perrin
jperrin@xxxxxxxxx 



**********************************************************
Electronic Mail is not secure, may not be read every day, and should not be 
used for urgent or sensitive issues
*************************************************************
You are receiving this mail because you subscribed to mso@xxxxxxxxxxxxx or 
MicrosoftOffice@xxxxxxxxxxxxxxxx

To send mail to the group, simply address it to mso@xxxxxxxxxxxxx

To Unsubscribe from this group, visit the group's homepage and use the dropdown 
menu at the top.  This will allow you to unsubscribe your email address or 
change your email settings to digest or vacation (no mail).
//www.freelists.org/webpage/mso

To be able to share files with the group, you must join our Yahoo sister 
group.  This group will not allow for posting of emails, but will allow you to 
join and share problem files, templates, etc.:  
http://tech.groups.yahoo.com/group/MicrosoftOffice . This group is for FILE 
SHARING ONLY.

If you are using Outlook and you see a lot of unnecessary code in your email 
messages, read these instructions that explain why and how to fix it:
http://personal-computer-tutor.com/abc3/v28/greg28.htm
*************************************************************



      
*************************************************************
You are receiving this mail because you subscribed to mso@xxxxxxxxxxxxx or 
MicrosoftOffice@xxxxxxxxxxxxxxxx

To send mail to the group, simply address it to mso@xxxxxxxxxxxxx

To Unsubscribe from this group, visit the group's homepage and use the dropdown 
menu at the top.  This will allow you to unsubscribe your email address or 
change your email settings to digest or vacation (no mail).
//www.freelists.org/webpage/mso

To be able to share files with the group, you must join our Yahoo sister group. 
 This group will not allow for posting of emails, but will allow you to join 
and share problem files, templates, etc.:  
http://tech.groups.yahoo.com/group/MicrosoftOffice . This group is for FILE 
SHARING ONLY.

If you are using Outlook and you see a lot of unnecessary code in your email 
messages, read these instructions that explain why and how to fix it:
http://personal-computer-tutor.com/abc3/v28/greg28.htm
*************************************************************

Other related posts: