Counting Days per Month in a Time Range (certain week days only)

excel_noob_

New Member
Joined
Mar 21, 2020
Messages
2
Office Version
  1. 2016
Hey everyone,

My question is the following:
I have a schedule for a set of connections A-C provided to you as per below screenshot and I would need to know is how often each connection is served in a respective calender month.



In case the “Day of Week” column entries aren’t self explanatory: for example - connection A is only served on the weekdays Mondays, Tuesdays, Saturdays & Sundays.



I am certain that the sumproduct function can be used to solve this problem – and by means of using workarounds I was already able to find out how to count the total number of frequencies in the timeframe. Unfortunately, I can’t figure out the missing AND criterion that would allow me to distinguish the number of frequencies per calendar month. Do you guys have a solution for this one?



Sincerely,

Finn
 

Some videos you may like

Excel Facts

Did you know Excel offers Filter by Selection?
Add the AutoFilter icon to the Quick Access Toolbar. Select a cell containing Apple, click AutoFilter, and you will get all rows with Apple

excel_noob_

New Member
Joined
Mar 21, 2020
Messages
2
Office Version
  1. 2016
Sorry forgot to attach the image. Point being: each connection is operative within a time range on specific days of weeks. The question is: how do I get the desired output? I am guessing with the sumproduct function?
 

Attachments

  • Workbook.png
    Workbook.png
    5.8 KB · Views: 8

jasonb75

Well-known Member
Joined
Dec 30, 2008
Messages
12,492
Office Version
  1. 365
Platform
  1. Windows
Welcome to Mr Excel, excel_noob_ aka Finn :)

I don't see a screenshot in your post, although screenshots are not of much use anyway. It would be better if you post a capture using XL2BB (green button on the reply box toolbar, then follow the instructions). That will provide a sample that we can copy and paste into excel to test formulas rather than having to manually retype your data.
 

jasonb75

Well-known Member
Joined
Dec 30, 2008
Messages
12,492
Office Version
  1. 365
Platform
  1. Windows
This should do what you need, I thought that NETWORKDAYS.INTL would be a better way to do it, but this proved more accurate.
Book2
ABCDEFGH
2ConnStartEndWeekdayMayJuneJuly
3a25/05/202002/06/202012…67420
4b04/06/202027/07/202012.4.6702019
5c12/06/202024/06/2020.2.4.67070
Sheet5
Cell Formulas
RangeFormula
F3:H5F3=SUMPRODUCT(ISNUMBER(SEARCH(WEEKDAY(ROW(INDEX($B:$B,$B3):INDEX($B:$B,$C3)),2),$D3))*(TEXT(ROW(INDEX($B:$B,$B3):INDEX($B:$B,$C3)),"mmmm")=F$2))
 

Watch MrExcel Video

Forum statistics

Threads
1,128,053
Messages
5,628,325
Members
416,311
Latest member
S991102

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