Consulting

Results 1 to 5 of 5

Thread: Solved: Find Max Value across Wkshts and display max in alert

  1. #1
    VBAX Regular
    Joined
    Jun 2007
    Posts
    20
    Location

    Solved: Find Max Value across Wkshts and display max in alert

    I have started this basic code that attempts to give me the max value throughout all worksheets, but have not defined a range (should be column A across all worksheets). An alert appears on each sheet, and I'd like it to add the largest value into an array and only output the max value from all worksheets once in a single alert, after having reached the last worksheet.

    [VBA]
    Sub ListMaxValuesFromSheet()
    For Each ws In ActiveWorkbook.Worksheets
    With ws
    MsgBox WorksheetFunction.Max(.UsedRange), vbExclamation
    ActiveSheet.Next.Select
    End With
    Next
    End Sub
    [/VBA]

    The idea is to find the last assigned bug tracker ID across all worksheets and have it displayed so the user knows where they left off.

  2. #2
    Mac Moderator VBAX Guru mikerickson's Avatar
    Joined
    May 2007
    Location
    Davis CA
    Posts
    2,778
    If you just want the Max value, this will get it without looping.[VBA]With ThisWorkbook
    MsgBox Evaluate("MAX(" & .Sheets(1).Name & ":" & .Sheets(.Sheets.Count).Name & "!A:A)")
    End With[/VBA]
    If you want to fill an array and report the maximum value
    [VBA]Dim SheetWiseMax() As Double
    Dim i As Long

    With ThisWorkbook
    ReDim SheetWiseMax(1 To .Sheets.Count)
    For i = 1 To .Sheets.Count
    SheetWiseMax(i) = Application.Max(.Sheets(i).Range("A:A"))
    Next i
    End With

    MsgBox Application.Max(SheetWiseMax) & " is the largest Column A value in the whole workbook."[/VBA]

  3. #3
    VBAX Regular
    Joined
    Jun 2007
    Posts
    20
    Location
    Wow, is that it? So something like so:

    [VBA]
    Sub ListMaxValuesFromSheet()
    Dim ws As Worksheet
    'For Each ws In ActiveWorkbook.Worksheets
    With ThisWorkbook
    MsgBox Evaluate("MAX(" & .Sheets(1).Name & ":" & .Sheets(.Sheets.Count).Name & "!A:A)")
    End With
    'Next
    End Sub
    [/VBA]

    However, I get a type mismatch. My guess is this is because I have text and numbers in the same column. I only want to get the max value where a number is present.

  4. #4
    Mac Moderator VBAX Guru mikerickson's Avatar
    Joined
    May 2007
    Location
    Davis CA
    Posts
    2,778
    That code works for me even with text in A:A, but Evaluate is quirky, perhaps this will work better on your system.
    [VBA]With ThisWorkbook
    MsgBox Evaluate("=MAX(" & .Sheets(1).Name & ":" & .Sheets(.Sheets.Count).Name & "!A:A)")
    End With[/VBA]

    If there are error values in A:A (eg. #DIV/0) that will cause the type mismatch.

    Also, it looks like you were posting while I was editing in the Array getting version above.

  5. #5
    VBAX Regular
    Joined
    Jun 2007
    Posts
    20
    Location
    Yes, I noticed that too.

    The second solution gave me what I needed. For some reason, I still got a type mismatch on the evaluate, but option 2 works flawlessly.

    Thanks!

Posting Permissions

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