Formula to count number of weekends within a rota.

Browneh89

Board Regular
Joined
Mar 8, 2019
Messages
55
Office Version
  1. 365
Platform
  1. Windows
Hello,

I would appreciate someone's help. I have a rota set out like the one below and I'm wondering if the is any variation of a count formula which would be able to allow me to count the number of weekend days each individual staff member has worked?

bob.xlsx
DEFGHIJKLMNOPQRSTUV
8Example Results
9SATURDAYS WORKEDSUNDAYS WORKED
10BOB21
11SUNDAYMONDAYTUESDAYWEDNESDAYTHURSDAYFRIDAYSATURDAYSUNDAYMONDAYTUESDAYWEDNESDAYTHURSDAYFRIDAYSATURDAYTIM01
1228/04/202129/04/202130/04/202101/05/202102/05/202103/05/202104/05/202105/05/202106/05/202107/05/202108/05/202109/05/202110/05/202111/05/2021
13
14BOB9am - 5pm9am - 5pm9am - 5pm9am - 5pm9am - 5pm9am - 5pm9am - 5pm9am - 5pm9am - 5pm9am - 5pm
15
16TIM9am - 5pm9am - 5pm9am - 5pm9am - 5pm9am - 5pm9am - 5pm9am - 5pm9am - 5pm9am - 5pm9am - 5pm
Sheet1
 

Some videos you may like

Excel Facts

Square and cube roots
The =SQRT(25) is a square root. For a cube root, use =125^(1/3). For a fourth root, use =625^(1/4).

jasonb75

Well-known Member
Joined
Dec 30, 2008
Messages
12,444
Office Version
  1. 365
Platform
  1. Windows
How about
Book1
TUV
8Example Results
9SATURDAYSUNDAY
10BOB21
11TIM01
Sheet5
Cell Formulas
RangeFormula
U10:V11U10=COUNTIFS($E$11:$R$11,U$9,INDEX($E$14:$R$16,MATCH($T10,$D$14:$D$16,0),0),"<>")
 

Eric W

MrExcel MVP
Joined
Aug 18, 2015
Messages
10,751
Another way:

=SUMPRODUCT(($E$13:$R$16<>"")*($D$13:$D$16=$T10)*($E$11:$R$11=U$9))

Although I suspect Jason's would be a bit faster on large ranges.
 

Browneh89

Board Regular
Joined
Mar 8, 2019
Messages
55
Office Version
  1. 365
Platform
  1. Windows
How about
Book1
TUV
8Example Results
9SATURDAYSUNDAY
10BOB21
11TIM01
Sheet5
Cell Formulas
RangeFormula
U10:V11U10=COUNTIFS($E$11:$R$11,U$9,INDEX($E$14:$R$16,MATCH($T10,$D$14:$D$16,0),0),"<>")

Thank you this worked perfectly!!
 

Browneh89

Board Regular
Joined
Mar 8, 2019
Messages
55
Office Version
  1. 365
Platform
  1. Windows

ADVERTISEMENT

Another way:

=SUMPRODUCT(($E$13:$R$16<>"")*($D$13:$D$16=$T10)*($E$11:$R$11=U$9))

Although I suspect Jason's would be a bit faster on large ranges.

Thanks, mate, unfortunately, this would be using a massive range!
 

jasonb75

Well-known Member
Joined
Dec 30, 2008
Messages
12,444
Office Version
  1. 365
Platform
  1. Windows
If you want an efficient formula for a large range then I would suggest deleting the empty row (15) and moving the results down a few rows.

Book1
TUV
11SATURDAYSUNDAY
12
13
14BOB21
15TIM01
Sheet5
Cell Formulas
RangeFormula
T14:T15T14=D14
U14:U15U14=COUNTA(K14,R14)
V14:V15V14=COUNTA(E14,L14)
 

Browneh89

Board Regular
Joined
Mar 8, 2019
Messages
55
Office Version
  1. 365
Platform
  1. Windows
If you want an efficient formula for a large range then I would suggest deleting the empty row (15) and moving the results down a few rows.

Book1
TUV
11SATURDAYSUNDAY
12
13
14BOB21
15TIM01
Sheet5
Cell Formulas
RangeFormula
T14:T15T14=D14
U14:U15U14=COUNTA(K14,R14)
V14:V15V14=COUNTA(E14,L14)

Thank you for your advice! however, those rows are needed for the sheet. What I posted on here was just a dummy sheet to represent the one I had to work on but does not contain everything within the actual sheet I am working upon.
 

jasonb75

Well-known Member
Joined
Dec 30, 2008
Messages
12,444
Office Version
  1. 365
Platform
  1. Windows
I had suspected that might be the case but it was worth mentioning on the off chance that it might work.
 

Watch MrExcel Video

Forum statistics

Threads
1,127,502
Messages
5,625,179
Members
416,076
Latest member
ralitsab

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
Top