Consulting

Results 1 to 10 of 10

Thread: List the 2nd Tuesday of the month for the next 12 months - Calculation Error

  1. #1
    Moderator VBAX Wizard Aussiebear's Avatar
    Joined
    Dec 2005
    Location
    Queensland
    Posts
    5,059
    Location

    List the 2nd Tuesday of the month for the next 12 months - Calculation Error

    I came across this file recently, whilst browsing on my phone. In trying to re create it in Excel, I'm coming up with a "Calc" error on my Mac (which suggests an empty array), but on MS system shows "#Name error", and when evaluating shows "TODAY" as underlined and "the next evaluation will result in an error" message. Can anyone assist me here please?

    =Let(start, EOMONTH(TODAY(), -1)+1, months,B5,n,B11,dow,B8, end,EDATE(start, months)-1, dates,SEQUENCE(end-start +1,1, start, 1), _
    dates,FILTER(dates,TEXT(dates,"dddd") = dow), instance, BYROW(dates,LAMBDA(d, SUM((TEXT(d, "mmyy") = TEXT(dates,"mmyy"))* _
    (d >= dates)))), FILTER(dates,instance = n))
    Attached Files Attached Files
    Last edited by Aussiebear; 09-30-2023 at 02:44 PM. Reason: Additional info supplied
    Remember To Do the Following....
    Use [Code].... [/Code] tags when posting code to the thread.
    Mark your thread as Solved if satisfied by using the Thread Tools options.
    If posting the same issue to another forum please show the link

  2. #2
    VBAX Mentor
    Joined
    Nov 2022
    Location
    The Great Land
    Posts
    337
    Location
    The only functions showing available for me are SUM() and TEXT() and EOMONTH(). I am using Excel 2010. What version are you using?

    Posted worksheet shows an array formula, your posted expression is not.
    https://support.microsoft.com/en-us/...2-ecfd5caa57c7

    Review https://www.myonlinetraininghub.com/...-in-each-month

    Why is this workbook an xlsm when there is no macro code?
    Last edited by June7; 09-30-2023 at 04:43 PM.
    How to attach file: Reading and Posting Messages (vbaexpress.com), click Go Advanced below post edit window. To provide db: copy, remove confidential data, run compact & repair, zip w/Windows Compression.

  3. #3
    Moderator VBAX Wizard Aussiebear's Avatar
    Joined
    Dec 2005
    Location
    Queensland
    Posts
    5,059
    Location
    Office 365 for Mac, That's what I was given, and in relation to XlSM, because its the start of a multiple sheeted workbook which will include code added as I go.
    Remember To Do the Following....
    Use [Code].... [/Code] tags when posting code to the thread.
    Mark your thread as Solved if satisfied by using the Thread Tools options.
    If posting the same issue to another forum please show the link

  4. #4
    VBAX Sage
    Joined
    Apr 2007
    Location
    United States
    Posts
    8,728
    Location
    That formula shows up here

    https://exceljet.net/formulas/list-n...s-of-the-month

    with a good explaination


    This

    FILTER(dates,TEXT(dates,"ddd")=dow)

    should be this

    FILTER(dates,TEXT(dates,"dddd")=dow)
    Attached Files Attached Files
    ---------------------------------------------------------------------------------------------------------------------

    Paul


    Remember: Tell us WHAT you want to do, not HOW you think you want to do it

    1. Use [CODE] ....[/CODE ] Tags for readability
    [CODE]PasteYourCodeHere[/CODE ] -- (or paste your code, select it, click [#] button)
    2. Upload an example
    Go Advanced / Attachments - Manage Attachments / Add Files / Select Files / Select the file(s) / Upload Files / Done
    3. Mark the thread as [Solved] when you have an answer
    Thread Tools (on the top right corner, above the first message)
    4. Read the Forum FAQ, especially the part about cross-posting in other forums
    http://www.vbaexpress.com/forum/faq...._new_faq_item3

  5. #5
    Moderator VBAX Wizard Aussiebear's Avatar
    Joined
    Dec 2005
    Location
    Queensland
    Posts
    5,059
    Location
    Thank you Paul. In the attached worksheet I've adjusted it to allow the User to choose the Number of Months, Select a day of the week, and the nth occurrence of the day selected (Maximum of 5). So if there's any association out there who wants to find the dates for a monthly meeting for the next couple of years..... You can Thank Dave at Exceljet.org and Paul Hossler from here.
    Attached Files Attached Files
    Remember To Do the Following....
    Use [Code].... [/Code] tags when posting code to the thread.
    Mark your thread as Solved if satisfied by using the Thread Tools options.
    If posting the same issue to another forum please show the link

  6. #6
    chip pearson has made similar function long time ago.
    VBA Procedures For Dates And Times (cpearson.com)

  7. #7
    Moderator VBAX Wizard Aussiebear's Avatar
    Joined
    Dec 2005
    Location
    Queensland
    Posts
    5,059
    Location
    Thank you arnelgp but I have a version which I have accepted as a solution
    Remember To Do the Following....
    Use [Code].... [/Code] tags when posting code to the thread.
    Mark your thread as Solved if satisfied by using the Thread Tools options.
    If posting the same issue to another forum please show the link

  8. #8

  9. #9
    Moderator VBAX Master georgiboy's Avatar
    Joined
    Mar 2008
    Location
    Kent, England
    Posts
    1,198
    Location
    Here are two shorter formulae without the use of LAMBDA, there are two options, one with text days of the week and one with numeric days of the week. The numeric days of the week formula is much shorter:

    Days of the week as text:
    =LET(
      d,MATCH(A8,{"Monday","Tuesday","Wednesday","Thursday","Friday","Saturday","Sunday"},0),
      WORKDAY.INTL(EOMONTH(TODAY(),SEQUENCE(A5)-2)+1,A11,REPLACE("1111111",d,1,"0"))
    )

    Numeric day of the week:
    =WORKDAY.INTL(EOMONTH(TODAY(),SEQUENCE(A5)-2)+1,A11,REPLACE("1111111",A8,1,"0"))
    Attached Files Attached Files
    Last edited by georgiboy; 10-02-2023 at 05:43 AM.
    Click here for a guide on how to add code tags
    Click here for a guide on how to mark a thread as solved
    Click here for a guide on how to upload a file with your post

    Excel 365, Version 2403, Build 17425.20146

  10. #10
    Moderator VBAX Wizard Aussiebear's Avatar
    Joined
    Dec 2005
    Location
    Queensland
    Posts
    5,059
    Location
    Just when I thought it was safe to go into the water.....
    Remember To Do the Following....
    Use [Code].... [/Code] tags when posting code to the thread.
    Mark your thread as Solved if satisfied by using the Thread Tools options.
    If posting the same issue to another forum please show the link

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •