FREQUENCY in a row with multiple condition

TomeK712

New Member
Joined
Aug 8, 2017
Messages
17
Office Version
  1. 2019
Platform
  1. Windows
Hello,

I do have a file with rota for associates with columns as a day of month and rows with names. As value use IN or OFF on certain days.
Occasionally I use 3rd value as OT for overtimes.

I need a formula which will indicate how many consecutive days was the associate working, and give the highest number.

I've managed to get it working for value IN only. I need to count both OT and IN as consecutive value.

Excel Formula:
{=MAX(FREQUENCY(IF(D45:AH45="IN",COLUMN(D45:AH45)),IF(D45:AH45<>"IN",COLUMN(D45:AH45))))}

Tried with IF(AND... but it doesn't work.

1641920159763.png
 

Excel Facts

Is there a shortcut key for strikethrough?
Ctrl+S is used for Save. Ctrl+5 is used for Strikethrough. Why Ctrl+5? When you use hashmarks to count |||| is 4, strike through to mean 5.
I suggest that you update your Account details (or click your user name at the top right of the forum) so helpers always know what Excel version(s) & platform(s) you are using as the best solution often varies by version. (Don’t forget to scroll down & ‘Save’)

Maybe
Excel Formula:
=MAX(FREQUENCY(IF((D4:AH4="IN")+(D4:AH4="OT"),COLUMN(D4:AH4)),IF((D4:AH4<>"IN")*(D4:AH4<>"OT"),COLUMN(D4:AH4))))
 
Upvote 0
Solution
Fantastic! Did not think about "+" option, tried to make it much more complicated ?

Thank you so much.
 
Upvote 0
You're welcome & thanks for the feedback.
 
Upvote 0

Forum statistics

Threads
1,213,543
Messages
6,114,240
Members
448,555
Latest member
RobertJones1986

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