Frequency formula.

Le_Me30

New Member
Joined
Jul 6, 2018
Messages
4
Hello All,

I would need someones help with frequency formula. never used it and now i need it for some of my work, i can come up with basic one but not with one with multiple criteria.
So here is what i need help on, i have a document with persons working times. Based on that i need to be able to calculate how many days they have worked by counting status "Connected" only once per day. I have below recreated the layout of the data. Criteria is based on country, weeks, persons ID, status what should be considered is "Connected". (please note that there will be drop downs and based on selected week and ID i need to be able to see their working days).
Hope the table makes sense :)

And thank you in advance!

ID

<tbody>
</tbody>
Surname

<tbody>
</tbody>
Name

<tbody>
</tbody>
STATUS

<tbody>
</tbody>
START

<tbody>
</tbody>
END

<tbody>
</tbody>
Country

<tbody>
</tbody>
WEEK

<tbody>
</tbody>
MONTH

<tbody>
</tbody>
Year

<tbody>
</tbody>
WEEKDAY

<tbody>
</tbody>
Country

<tbody>
</tbody>
UK<- This is dropdown
12345

<tbody>
</tbody>
SMITH

<tbody>
</tbody>
John

<tbody>
</tbody>
ON_SITE

<tbody>
</tbody>
18-06-18

<tbody>
</tbody>
18-06-18

<tbody>
</tbody>
UK2562018MondayWeek25<- This is dropdown
12345

<tbody>
</tbody>
SMITH

<tbody>
</tbody>
John

<tbody>
</tbody>
CONNECTED

<tbody>
</tbody>
18-06-18

<tbody>
</tbody>
18-06-18

<tbody>
</tbody>
UK2562018MondayID1234<- This is dropdown
12345

<tbody>
</tbody>
SMITH

<tbody>
</tbody>
John

<tbody>
</tbody>
CONNECTED

<tbody>
</tbody>
18-06-18

<tbody>
</tbody>
18-06-18

<tbody>
</tbody>
UK2562018MondayDays worked??Based on statuses "Connected".
12345

<tbody>
</tbody>
SMITH

<tbody>
</tbody>
John

<tbody>
</tbody>
READY

<tbody>
</tbody>
18-06-18

<tbody>
</tbody>
18-06-18

<tbody>
</tbody>
UK2562018MondayResult should be4
12345

<tbody>
</tbody>
SMITH

<tbody>
</tbody>
John

<tbody>
</tbody>
Unavailable

<tbody>
</tbody>
18-06-18

<tbody>
</tbody>
18-06-18

<tbody>
</tbody>
UK2562018Monday
12345

<tbody>
</tbody>
SMITH

<tbody>
</tbody>
John

<tbody>
</tbody>
CONNECTED

<tbody>
</tbody>
18-06-18

<tbody>
</tbody>
18-06-18

<tbody>
</tbody>
UK2562018Monday
12345

<tbody>
</tbody>
SMITH

<tbody>
</tbody>
John

<tbody>
</tbody>
WRAPUP

<tbody>
</tbody>
19-06-18

<tbody>
</tbody>
19-06-18

<tbody>
</tbody>
UK2562018Tuesday
12345

<tbody>
</tbody>
SMITH

<tbody>
</tbody>
John

<tbody>
</tbody>
WRAPUP

<tbody>
</tbody>
19-06-18

<tbody>
</tbody>
19-06-18

<tbody>
</tbody>
UK2562018Tuesday
12345

<tbody>
</tbody>
SMITH

<tbody>
</tbody>
John

<tbody>
</tbody>
WRAPUP

<tbody>
</tbody>
19-06-18

<tbody>
</tbody>
19-06-18

<tbody>
</tbody>
UK2562018Tuesday
12345

<tbody>
</tbody>
SMITH

<tbody>
</tbody>
John

<tbody>
</tbody>
CONNECTED

<tbody>
</tbody>
19-06-18

<tbody>
</tbody>
19-06-18

<tbody>
</tbody>
UK2562018Tuesday
12345

<tbody>
</tbody>
SMITH

<tbody>
</tbody>
John

<tbody>
</tbody>
READY

<tbody>
</tbody>
19-06-18

<tbody>
</tbody>
19-06-18

<tbody>
</tbody>
UK2562018Tuesday
12345

<tbody>
</tbody>
SMITH

<tbody>
</tbody>
John

<tbody>
</tbody>
ON_SITE

<tbody>
</tbody>
20-06-18

<tbody>
</tbody>
20-06-18

<tbody>
</tbody>
UK2562018Wednesday
12345

<tbody>
</tbody>
SMITH

<tbody>
</tbody>
John

<tbody>
</tbody>
CONNECTED

<tbody>
</tbody>
20-06-18

<tbody>
</tbody>
20-06-18

<tbody>
</tbody>
UK2562018Wednesday
12345

<tbody>
</tbody>
SMITH

<tbody>
</tbody>
John

<tbody>
</tbody>
CONNECTED

<tbody>
</tbody>
20-06-18

<tbody>
</tbody>
20-06-18

<tbody>
</tbody>
UK2562018Wednesday
12345

<tbody>
</tbody>
SMITH

<tbody>
</tbody>
John

<tbody>
</tbody>
READY

<tbody>
</tbody>
20-06-18

<tbody>
</tbody>
20-06-18

<tbody>
</tbody>
UK2562018Wednesday
12345

<tbody>
</tbody>
SMITH

<tbody>
</tbody>
John

<tbody>
</tbody>
Unavailable

<tbody>
</tbody>
21-06-18

<tbody>
</tbody>
21-06-18

<tbody>
</tbody>
UK2562018Thursday
12345

<tbody>
</tbody>
SMITH

<tbody>
</tbody>
John

<tbody>
</tbody>
CONNECTED

<tbody>
</tbody>
21-06-18

<tbody>
</tbody>
21-06-18

<tbody>
</tbody>
UK2562018Thursday
12345

<tbody>
</tbody>
SMITH

<tbody>
</tbody>

<tbody>
</tbody>
John

<tbody>
</tbody>
CONNECTED

<tbody>
</tbody>
21-06-18

<tbody>
</tbody>
21-06-18

<tbody>
</tbody>
UK2562018Thursday
12345

<tbody>
</tbody>
SMITH

<tbody>
</tbody>
John

<tbody>
</tbody>
READY

<tbody>
</tbody>
21-06-18

<tbody>
</tbody>
21-06-18

<tbody>
</tbody>
UK2562018Thursday
12345

<tbody>
</tbody>
SMITH

<tbody>
</tbody>
John

<tbody>
</tbody>
ON_SITE

<tbody>
</tbody>
21-06-18

<tbody>
</tbody>
21-06-18

<tbody>
</tbody>
UK2562018Thursday
12345

<tbody>
</tbody>
SMITH

<tbody>
</tbody>
John

<tbody>
</tbody>
READY

<tbody>
</tbody>
21-06-18

<tbody>
</tbody>
21-06-18

<tbody>
</tbody>
UK2562018Thursday

<tbody>
</tbody>
 

Excel Facts

What do {} around a formula in the formula bar mean?
{Formula} means the formula was entered using Ctrl+Shift+Enter signifying an old-style array formula.
Re: Need help with freequency formula.

Do we need to consider the start date AND the end date...or are they always equal?
 
Upvote 0
Re: Need help with freequency formula.

I put your sample data in an Excel Table named Table1 (In A1:K22).
and these values in O1:P4
Code:
Country          UK
Week             25
ID            12345
Days worked? ?
Last, this regular formula returns the number of unique START dates worked for the matching
Country, Week and ID for Status = Connected
Code:
P4: =SUMPRODUCT(--(MATCH(P3&"|CONNECTED|"&P1&"|"&P2&"|"&Table1[START]
,INDEX(Table1[ID]&"|"&Table1[STATUS]&"|"&Table1[Country]&"|"&Table1[WEEK]&"|"&Table1[START],0),0)
=(ROW(Table1[ID])-ROW(Table1[[#Headers],[ID]]))))
Is that something you can work with?
 
Upvote 0
Re: Need help with freequency formula.

I put your sample data in an Excel Table named Table1 (In A1:K22).
and these values in O1:P4
Code:
Country          UK
Week             25
ID            12345
Days worked? ?
Last, this regular formula returns the number of unique START dates worked for the matching
Country, Week and ID for Status = Connected
Code:
P4: =SUMPRODUCT(--(MATCH(P3&"|CONNECTED|"&P1&"|"&P2&"|"&Table1[START]
,INDEX(Table1[ID]&"|"&Table1[STATUS]&"|"&Table1[Country]&"|"&Table1[WEEK]&"|"&Table1[START],0),0)
=(ROW(Table1[ID])-ROW(Table1[[#Headers],[ID]]))))
Is that something you can work with?

Thank you so much, it works perfectly! You have saved my day.
 
Upvote 0

Forum statistics

Threads
1,216,129
Messages
6,129,047
Members
449,482
Latest member
al mugheen

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