Separating Hourly Time Periods in a Day

Zero1985

New Member
Joined
Dec 12, 2014
Messages
6
Hello, I need help creating Excel formulas that separates hours in a day by three different time periods. The time periods are:

· Period 1: 10 p.m. to 6 a.m. Everyday

· Period 2: 4 p.m. to 7 p.m. Mondaythrough Friday (except Federal Holidays)

· Period 3: 6 a.m. to 4 p.m. AND 7 p.m. to 10 p.m. Monday through Friday, and 6 a.m. to 10 p.m. on Saturday, Sunday and Federal Holidays


An Excel formula for each period is fine. Any help is greatly appreciated. Thanks!
 

Excel Facts

Format cells as currency
Select range and press Ctrl+Shift+4 to format cells as currency. (Shift 4 is the $ sign).
  1. Where are these formulas being used?
  2. Do you want the start and end times in one cell or separate cells?
  3. Do you need the descriptive text as well (i.e. Everyday, Monday through Friday ..... )?
  4. Is Period three really three separate periods?
 
Upvote 0
  1. Where are these formulas being used?
  2. Do you want the start and end times in one cell or separate cells?
  3. Do you need the descriptive text as well (i.e. Everyday, Monday through Friday ..... )?
  4. Is Period three really three separate periods?
I have a column labeled Hour which lists 1 through 24 in descending order. (Hours in a day) Then I have three separate columns for each period to differentiate the “Hour” column. I just need help creating the formula to satisfy each of those periods.
 
Upvote 0
well, my setup is sligthly different. It is unclear where you get the dates/days from.
So you can use the solution below and build on it:

...
ABCDEFGHIJ
1time 16 to 19is work day
2holidaysDate & Timeday nameday num1222PERIOD
315.07.202120.07.2021 05:31 Tuesday2TRUEFALSETRUEFALSE1
415.07.202119.07.2021 17:31 Monday1FALSETRUETRUETRUE2
512.07.202118.07.2021 17:31 Sunday7FALSETRUEFALSEFALSE3
607.07.202117.07.2021 12:43 Saturday6FALSEFALSEFALSEFALSE3
730.06.202116.07.2021 17:31 Friday5FALSETRUETRUETRUE2
824.06.202115.07.2021 19:55 Thursday4FALSEFALSEFALSEFALSE3
918.06.202115.07.2021 05:31 Thursday4TRUEFALSEFALSEFALSE1
1011.06.202112.07.2021 00:43 Monday1TRUEFALSEFALSEFALSE1
1107.07.2021 12:43 Wednesday3FALSEFALSEFALSEFALSE3
1230.06.2021 12:43 Wednesday3FALSEFALSEFALSEFALSE3
1324.06.2021 12:43 Thursday4FALSEFALSEFALSEFALSE3
1418.06.2021 00:43 Friday5TRUEFALSEFALSEFALSE1
1511.06.2021 00:43 Friday5TRUEFALSEFALSEFALSE1
Sheet1 (2)
Cell Formulas
RangeFormula
D3:D15D3=TEXT(C3,"[$-en-US] dddd")
E3:E15E3=WEEKDAY(C3,2)
F3:F15F3=OR(C3-INT(C3)>=TIME(22,0,0),C3-INT(C3)<=TIME(6,0,0))
G3:G15G3=AND(C3-INT(C3)>=TIME(16,0,0),C3-INT(C3)<=TIME(19,0,0))
H3:H15H3=INT(C3)=WORKDAY.INTL(C3-1,1,1,$A$3:$A$10)
I3:I15I3=AND(C3-INT(C3)>=TIME(16,0,0),C3-INT(C3)<=TIME(19,0,0),INT(C3)=WORKDAY.INTL(C3-1,1,1,$A$3:$A$10))
J3:J15J3=IF( OR(C3-INT(C3)>=TIME(22,0,0),C3-INT(C3)<=TIME(6,0,0)),1, IF( AND(C3-INT(C3)>=TIME(16,0,0),C3-INT(C3)<=TIME(19,0,0),INT(C3)=WORKDAY.INTL(C3-1,1,1,$A$3:$A$10)),2,3))


the formula is in column J
You only need the columns in yellow
 
Upvote 0
I have a column labeled Hour which lists 1 through 24 in descending order. (Hours in a day) Then I have three separate columns for each period to differentiate the “Hour” column. I just need help creating the formula to satisfy each of those periods.
Where do you get the day of the week? It would be really helpful if you could post your worksheet with the XL2BB tool.
 
Upvote 0

Forum statistics

Threads
1,213,484
Messages
6,113,924
Members
448,533
Latest member
thietbibeboiwasaco

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