Home |
Search |
Today's Posts |
|
#1
![]()
Posted to microsoft.public.excel.worksheet.functions
|
|||
|
|||
![]()
I would like to create a monthly inventory, based on workdays (Monday -
Friday)Myrna Larson has a formula that I would like to use with the workday function, but I don't know how to combine them. =IF(A1="",A1,IF(MONTH(A1+1)=MONTH(A1),A1+1,"")) + =workday to fit on the page, I need the dates to be from the 1st to the 15th, and 16th to the 31st. I am not sure how to write this either. Thank you for your response. Monique |
#2
![]()
Posted to microsoft.public.excel.worksheet.functions
|
|||
|
|||
![]() Monique, Assuming that your start date is in A1 (entered manually) and your range is A1:L1 for 1-15 then in B1 enter: =IF(A1="","",IF(DAY(WORKDAY(A1,1))15,"",WORKDAY(A 1,1))) Copy this over to L1 Not sure where you are putting your 16 - 31 but for this example say it is A6:L6 In A6: =WORKDAY(MAX(A1:L1),1) In B6 =IF(A6="","",IF(DAY(WORKDAY(A6,1))31,"",IF(MONTH( A6+1)MONTH(A1),"",WORKDAY(A6,1)))) Copy this over to L6. Does that help? Steve -- SteveG ------------------------------------------------------------------------ SteveG's Profile: http://www.excelforum.com/member.php...fo&userid=7571 View this thread: http://www.excelforum.com/showthread...hreadid=537695 |
#3
![]()
Posted to microsoft.public.excel.worksheet.functions
|
|||
|
|||
![]()
I checked a few of the months, and December and September are adding one or
two day of the next month. I am not sure why. "SteveG" wrote: Monique, Assuming that your start date is in A1 (entered manually) and your range is A1:L1 for 1-15 then in B1 enter: =IF(A1="","",IF(DAY(WORKDAY(A1,1))15,"",WORKDAY(A 1,1))) Copy this over to L1 Not sure where you are putting your 16 - 31 but for this example say it is A6:L6 In A6: =WORKDAY(MAX(A1:L1),1) In B6 =IF(A6="","",IF(DAY(WORKDAY(A6,1))31,"",IF(MONTH( A6+1)MONTH(A1),"",WORKDAY(A6,1)))) Copy this over to L6. Does that help? Steve -- SteveG ------------------------------------------------------------------------ SteveG's Profile: http://www.excelforum.com/member.php...fo&userid=7571 View this thread: http://www.excelforum.com/showthread...hreadid=537695 |
#4
![]()
Posted to microsoft.public.excel.worksheet.functions
|
|||
|
|||
![]() Monique, This should do it for you. I checked this for each month of 2006. =IF(A6="","",IF(DAY(WORKDAY(A6,1))31,"",IF(MONTH( WORKDAY(A6,1))MONTH($A$1),"",IF(YEAR(WORKDAY(A6,1 ))YEAR(A1),"",WORKDAY(A6,1))))) Copy accross to L6. Regards, Steve -- SteveG ------------------------------------------------------------------------ SteveG's Profile: http://www.excelforum.com/member.php...fo&userid=7571 View this thread: http://www.excelforum.com/showthread...hreadid=537695 |
#5
![]()
Posted to microsoft.public.excel.worksheet.functions
|
|||
|
|||
![]()
Thanks Steve! It worked like a charm!
"Monique" wrote: I would like to create a monthly inventory, based on workdays (Monday - Friday)Myrna Larson has a formula that I would like to use with the workday function, but I don't know how to combine them. =IF(A1="",A1,IF(MONTH(A1+1)=MONTH(A1),A1+1,"")) + =workday to fit on the page, I need the dates to be from the 1st to the 15th, and 16th to the 31st. I am not sure how to write this either. Thank you for your response. Monique |
#6
![]()
Posted to microsoft.public.excel.worksheet.functions
|
|||
|
|||
![]() I played around with the cell on the last day and changed the formula in K6. It seems to work the way I intended it to. Thanks for helping me figure out the hard part! =IF(K6="","",IF(DAY(WORKDAY(K6,1))31,"",IF(MONTH( K6+1)MONTH(L1),"",WORKDAY(K6,1)))) "Monique" wrote: Thanks Steve! It worked like a charm! "Monique" wrote: I would like to create a monthly inventory, based on workdays (Monday - Friday)Myrna Larson has a formula that I would like to use with the workday function, but I don't know how to combine them. =IF(A1="",A1,IF(MONTH(A1+1)=MONTH(A1),A1+1,"")) + =workday to fit on the page, I need the dates to be from the 1st to the 15th, and 16th to the 31st. I am not sure how to write this either. Thank you for your response. Monique |
#7
![]()
Posted to microsoft.public.excel.worksheet.functions
|
|||
|
|||
![]() Slight typo. You need to change the A1 in the YEAR formula to an absolute reference. =IF(A6="","",IF(DAY(WORKDAY(A6,1))31,"",IF(MONTH( WORKDAY(A6,1))MONTH($A$1),"",IF(YEAR(WORKDAY(A6,1 ))YEAR($A$1),"",WORKDAY(A6,1))))) -- SteveG ------------------------------------------------------------------------ SteveG's Profile: http://www.excelforum.com/member.php...fo&userid=7571 View this thread: http://www.excelforum.com/showthread...hreadid=537695 |
#8
![]()
Posted to microsoft.public.excel.worksheet.functions
|
|||
|
|||
![]()
Can you explain the need for:
IF(DAY(WORKDAY(A6,1))31,"", That expression will never be TRUE. Biff "SteveG" wrote in message ... Slight typo. You need to change the A1 in the YEAR formula to an absolute reference. =IF(A6="","",IF(DAY(WORKDAY(A6,1))31,"",IF(MONTH( WORKDAY(A6,1))MONTH($A$1),"",IF(YEAR(WORKDAY(A6,1 ))YEAR($A$1),"",WORKDAY(A6,1))))) -- SteveG ------------------------------------------------------------------------ SteveG's Profile: http://www.excelforum.com/member.php...fo&userid=7571 View this thread: http://www.excelforum.com/showthread...hreadid=537695 |
#9
![]()
Posted to microsoft.public.excel.worksheet.functions
|
|||
|
|||
![]() Biff, Good point. I was following my logic not to exceed the 15th of the month by using [ =IF(DAY(WORKDAY(A1,1))15,"", ]. Of course it is not needed unless someone decides to change our date systems and make 32 day months. Thanks for catching that. Steve -- SteveG ------------------------------------------------------------------------ SteveG's Profile: http://www.excelforum.com/member.php...fo&userid=7571 View this thread: http://www.excelforum.com/showthread...hreadid=537695 |
#10
![]()
Posted to microsoft.public.excel.worksheet.functions
|
|||
|
|||
![]() SteveG Wrote: Slight typo. You need to change the A1 in the YEAR formula to an absolute reference. =IF(A6="","",IF(DAY(WORKDAY(A6,1))31,"",IF(MONTH( WORKDAY(A6,1))MONTH($A$1),"",IF(YEAR(WORKDAY(A6,1 ))YEAR($A$1),"",WORKDAY(A6,1))))) Hi Steve/Monique checking IF(DAY(WORKDAY(A6,1))31 is redundant since it can never be true. Won't this formula in B6 copied across be sufficient? =IF(A6="","",IF(MONTH(WORKDAY(A6,1))<MONTH(A6),"" ,WORKDAY(A6,1))) -- daddylonglegs ------------------------------------------------------------------------ daddylonglegs's Profile: http://www.excelforum.com/member.php...o&userid=30486 View this thread: http://www.excelforum.com/showthread...hreadid=537695 |
#11
![]()
Posted to microsoft.public.excel.worksheet.functions
|
|||
|
|||
![]()
Hi Steve,
I did copy and paste this part. It shows up as: =IF(A6="","",IF(DAY(WORKDAY(A6,1))31,"",IF(MONTH( WORKDAY(A6,1))MONTH($A$1),"",IF(YEAR(WORKDAY(A6,1 ))YEAR($A$1),"",WORKDAY(A6,1))))) Perhaps there is a missing piece. Monique "daddylonglegs" wrote: SteveG Wrote: Slight typo. You need to change the A1 in the YEAR formula to an absolute reference. =IF(A6="","",IF(DAY(WORKDAY(A6,1))31,"",IF(MONTH( WORKDAY(A6,1))MONTH($A$1),"",IF(YEAR(WORKDAY(A6,1 ))YEAR($A$1),"",WORKDAY(A6,1))))) Hi Steve/Monique checking IF(DAY(WORKDAY(A6,1))31 is redundant since it can never be true. Won't this formula in B6 copied across be sufficient? =IF(A6="","",IF(MONTH(WORKDAY(A6,1))<MONTH(A6),"" ,WORKDAY(A6,1))) -- daddylonglegs ------------------------------------------------------------------------ daddylonglegs's Profile: http://www.excelforum.com/member.php...o&userid=30486 View this thread: http://www.excelforum.com/showthread...hreadid=537695 |
Reply |
Thread Tools | Search this Thread |
Display Modes | |
|
|
![]() |
||||
Thread | Forum | |||
Custom functions calculating time arguments Help Desperate | Excel Worksheet Functions | |||
i have two days and i want the difference in days, months, year | Excel Worksheet Functions | |||
Function or formula to convert "text" month to number of month | Excel Discussion (Misc queries) | |||
4 and 5 week months | Excel Discussion (Misc queries) | |||
Calculating recurring date in following month, calculating # days in that period | Excel Worksheet Functions |