• Capture Month for Reporting (Excel 2003)

    Home » Forums » AskWoody support » Productivity software by function » MS Excel and spreadsheet help » Capture Month for Reporting (Excel 2003)

    Author
    Topic
    #447090

    Hi Excel Experts,

    In our organisation, all our monthly reports are from 26th of current month 25th of subsequent month. I have created a formula to pick the month based on the same. However i have a small problem with the same when there are months with 31 and 30 days.

    =TEXT(IF(DAY($L2)<26,DATE(YEAR($L2),MONTH($L2),DAY($L2)),DATE(YEAR($L2),MONTH($L2)+1,DAY($L2))),"mmmm-yy")

    In the above formula if the date is 31st-Oct then the month comes as December and not November since there are only 30 days in nov. is there a way to fix this.

    Regards
    Baiju

    Viewing 1 reply thread
    Author
    Replies
    • #1088865

      Baiju

      I think if you replace the DAY($L2) with 1 in the formula it should work correctly.

      Nick

    • #1088866

      Since you are not putting the day down, how about:
      =TEXT(IF(DAY($L2)<26,DATE(YEAR($L2),MONTH($L2),DAY($L2)),DATE(YEAR($L2),MONTH($L2)+1,1)),"mmmm-yy")

      You move an extra month since if the next month does not have 31 days, it goes to the next month. If the date is Oct 31, then your formula wants the Month/year for "november 31" = Dec 1 since nov has only 30 days. If you just use the 1st you don't ever "turn over" the month.

      Steve

      • #1088870

        Thanks Steve & Nick its working fine now.

        • #1088871

          Just as an alternative version:
          =TEXT(DATE(YEAR($L2),MONTH($L2)+(DAY($L2)>25),1),"mmmm-yy")
          FWIW.

    Viewing 1 reply thread
    Reply To: Capture Month for Reporting (Excel 2003)

    You can use BBCodes to format your content.
    Your account can't use all available BBCodes, they will be stripped before saving.

    Your information: