formula help

sam__gleeson

Board Regular
Joined
Oct 11, 2012
Messages
102
I have this formula looking at range D7:AH7 for the word sick..can the formula not count the weekends?

Code:
=COUNTIF($D7:$AH7,"SICK")

Cheers
 

Excel Facts

How to total the visible cells?
From the first blank cell below a filtered data set, press Alt+=. Instead of SUM, you will get SUBTOTAL(9,)
Does this work for you?

=SUMPRODUCT(--($D$7:$AH$7="SICK"),--(WEEKDAY($D$6:$AH$6,3)<5))

I assumed you meant D6:AH6 not C6:AH6
 
Upvote 0
Does this work for you?

=SUMPRODUCT(--($D$7:$AH$7="SICK"),--(WEEKDAY($D$6:$AH$6,3)<5))

I assumed you meant D6:AH6 not C6:AH6

Yes your correct about the range

Yes formula works great....how does the formula work please?

What are the lines hightlighted red in your formula?

Thanks
 
Upvote 0
It's called a double unary. It is used to convert an internal array of TRUE/FALSE into 1/0

This is a good source for further explanations.

http://xldynamic.com/source/xld.SUMPRODUCT.html

The Weekday part tests the weekday of the date which ends up giving you...

{3,4,5,6,0,1,2,3,4,5,6,0,1,2,5,5,5,5,5,5,5,5,5,5,5,5,5,5,5,5,5}<5)

Now when you check for less than 5 (Sat and Sun), the numbers turn into TRUE/FALSE which is multiplied by the first TRUE/FALSE looking for the word "SICK".

To get a better understanding of how and what a formula is doing, use the Evaluate Formula function
 
Upvote 0
hi .

is this shorter ? seems to work with me: (FRI - SAT = OFFDAYS)

@ E7
Code:
[COLOR=#333333][FONT=Verdana]=SUMPRODUCT([/FONT][/COLOR][COLOR=Blue][FONT=Verdana]([COLOR=Red]WEEKDAY([COLOR=Green]E3:T3[/COLOR])<6[/COLOR])*([COLOR=Red]E4:T4="SICK"[/COLOR])[/FONT][/COLOR][COLOR=#333333][FONT=Verdana])[/FONT][/COLOR]



Excel 2010
EFGHIJKLMNOPQRST
2FSSSMTWTHFSSSMTWTHFS
31-Jan-162-Jan-163-Jan-164-Jan-165-Jan-166-Jan-167-Jan-168-Jan-169-Jan-1610-Jan-1611-Jan-1612-Jan-1613-Jan-1614-Jan-1615-Jan-1616-Jan-16
4SICKSICKSICKSICKSICKSICK
5
6
73
Sheet1
 
Upvote 0

Forum statistics

Threads
1,213,522
Messages
6,114,112
Members
448,549
Latest member
brianhfield

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