Formula to count months

Glacombe

Board Regular
Joined
Oct 31, 2018
Messages
101
Office Version
  1. 2016
Platform
  1. Windows
Hello
I have the following formula that counts how many months worked in a fiscal year and not counting holidays and also if worked 10 or more days in the month it will count that month. The formula verifies the start date which is in AJ10 and the end date which is in AK10.

=IF(AND(ISBLANK(AJ10),ISBLANK(AK10)),0,(YEAR(AK10)-YEAR(AJ10))*12+MONTH(AK10)-MONTH(AJ10)-1+IF(NETWORKDAYS.INTL(AJ10,EOMONTH(AJ10,0))>=10,1,0)+IF(NETWORKDAYS.INTL(EOMONTH(AK10,-1),AK10,1)>=10,1,0))

What I am trying to revise this formula is to count if worked half the month to count it. For example if the period would be April 1, 2020 to September 15, 2020, I would like the result of the formula to show 5.5 months instead 6.
 

Glacombe

Board Regular
Joined
Oct 31, 2018
Messages
101
Office Version
  1. 2016
Platform
  1. Windows
Because the end date is Dec 1, it will not count that month, it will make a full month if the person was working the entire month
 

Excel Facts

When did Power Query debut in Excel?
Although it was an add-in in Excel 2010 & Excel 2013, Power Query became a part of Excel in 2016, in Data, Get & Transform Data.

JamesCanale

Active Member
Joined
Jan 13, 2021
Messages
289
Office Version
  1. 365
Platform
  1. Windows
  2. MacOS
I meant the start date - what if it started on April 2, would that be a full month? How many work days is a full month? Only from the first?
 

Glacombe

Board Regular
Joined
Oct 31, 2018
Messages
101
Office Version
  1. 2016
Platform
  1. Windows
Yes the start date if it would be April 2 that would make it a full month thanks
 

Glacombe

Board Regular
Joined
Oct 31, 2018
Messages
101
Office Version
  1. 2016
Platform
  1. Windows
If they start in the middle of the month, that would make it half a month and also if they end in the middle of the month it would also be a half month
 

Glacombe

Board Regular
Joined
Oct 31, 2018
Messages
101
Office Version
  1. 2016
Platform
  1. Windows

ADVERTISEMENT

So that would probably be the IF(NETWORKDAYS.INTL identifying AJ and AK would be and IF(AND or IF(OR for both right?
 

JamesCanale

Active Member
Joined
Jan 13, 2021
Messages
289
Office Version
  1. 365
Platform
  1. Windows
  2. MacOS
So, if the networkdays >=18 you get a whole month, if it's >= 8 you get a half month, and if it's less than that, you get 0:
MrExcelPlayground.xlsm
AJAKAL
104/1/20211/15/20229.5
Sheet16
Cell Formulas
RangeFormula
AL10AL10=IF(OR(AJ10="",AK10=""),"",((YEAR(AK10)*12+MONTH(AK10))-(YEAR(AJ10)*12+MONTH(AJ10))-1)+IF(NETWORKDAYS.INTL(AJ10,EOMONTH(AJ10,0),1)>=18,1,IF(NETWORKDAYS.INTL(AJ10,EOMONTH(AJ10,0),1)>=8,0.5,0))+IF(NETWORKDAYS.INTL(DATE(YEAR(AK10),MONTH(AK10),1),AK10,1)>=18,1,IF(NETWORKDAYS.INTL(DATE(YEAR(AK10),MONTH(AK10),1),AK10,1)>=8,0.5,0)))

You can tweak those values as you see fit in there. You can see two ">=18" and two ">=8".
 
Solution

Glacombe

Board Regular
Joined
Oct 31, 2018
Messages
101
Office Version
  1. 2016
Platform
  1. Windows
Super it works perfectly thank you again James for all your patience
 

Forum statistics

Threads
1,141,002
Messages
5,703,663
Members
421,310
Latest member
CindaH

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