Hi sijpie ,

I was wondering if you could help me about modifying this script you wrote before?

Currently this script gives user the option to select a range in each worksheet when the range is selected then it moves to the next worksheet. Is it possible to add a warning message before moving to the next tab? The thing is some worksheets require multiple calculations based on more than one range. Can we add yes no message box saying "would you like to move to the next worksheet?" If no was clicked then it would ask to select another range in the same worksheet if yes was clicked then it would move to the next tab?? I don't know if there is another way to be able to select multiple ranges for the calculations in a single worksheet.

Quote Originally Posted by sijpie View Post
Option Explicit




'------------------------------------------------
Sub CreateSummary()
'
' Macro to create summary table containing the _
  Min, Max, and 3 Quartiles of each sheet in _
  the workbook. The user is requested to _
  input the first cell of the range for the _
  calculations. In addition the value of the _
  row at 'Z' (in column C) is entered in the _
  table.
'------------------------------------------------
    Dim rInp As Range, rOut As Range, rFnd As Range, rSrch As Range
    Dim wsIn As Worksheet, wsSum As Worksheet
    Dim lR As Long
    Dim vOut As Variant
    Const sZZZ As String = "Z" ' This is the value to indicate special row
    Const iCCC As Integer = 3   'Column C where sZZZ is to be searched
    
    ' Check if Summary sheet exists, else create
    On Error Resume Next    'in case it doesn't exist
    Set wsSum = Sheets("Summary")
    On Error GoTo 0         ' reset error behaviour
    If wsSum Is Nothing Then    ' sheet does not exist
        Set wsSum = Sheets.Add(after:=Sheets(Sheets.Count))
        wsSum.Name = "Summary"
    End If
    Set rOut = wsSum.Range("D2")
    
    'for our output we will gather the data into an array _
     then print out a row at once for each sheet. _
     first the header:
    ReDim vOut(1 To 1, 1 To 7)
    vOut(1, 2) = "Z"
    vOut(1, 3) = "Min"
    vOut(1, 4) = "Q1"
    vOut(1, 5) = "Q2"
    vOut(1, 6) = "Q3"
    vOut(1, 7) = "Max"
    rOut.Resize(1, 7).Value = vOut 'print headers to sheet
    Set rOut = rOut.Offset(1, 0) ' set to next row
    
    ' Now go through each sheet, get user to enter _
      range for processing. Then calculate quartiles _
      and add the Z figure.
    
    For Each wsIn In Sheets
        If wsIn.Name <> wsSum.Name Then
GetRange:
            wsIn.Activate
            Set rInp = Application.InputBox( _
                prompt:="Please select 1st cell of range in this sheet " _
                & vbCrLf & "to be processed for Quartiles." & vbCrLf _
                & " You can use your mouse to select", _
                Title:="Select Quartiles Range", _
                Type:=8)
            If rInp Is Nothing Then GoTo GetRange    ' loop if invalid input
            If rInp.Columns.Count > 1 Or rInp.Parent.Name <> wsIn.Name _
                Then GoTo GetRange ' loop if multiple columns selected or on wrong sheet
            
            ' extend range to end of sheet
            lR = wsIn.Cells(Rows.Count, rInp.Column).End(xlUp).Row '  last row, now skip summary
            lR = wsIn.Cells(lR, rInp.Column).End(xlUp).Row '
            Set rInp = rInp.Cells(1, 1).Resize(lR - rInp.Row + 1, 1)
            ' calculate quartiles from provided range
            With Application.WorksheetFunction
                vOut(1, 1) = wsIn.Name
                vOut(1, 3) = .Min(rInp)
                vOut(1, 4) = .Quartile(rInp, 1)
                vOut(1, 5) = .Quartile(rInp, 2)
                vOut(1, 6) = .Quartile(rInp, 3)
                vOut(1, 7) = .Max(rInp)
            End With
            'find the 'Z'
            Set rSrch = wsIn.Columns(iCCC)
            Set rFnd = rSrch.Find(what:=sZZZ, after:=Cells(rInp.Row - 1, 3), _
                 lookat:=xlWhole, LookIn:=xlValues, _
                 searchdirection:=xlNext)
            If rFnd Is Nothing Then ' not found
                vOut(1, 2) = vbNullString
            Else    ' get value at intersection of column and row
                vOut(1, 2) = Intersect(rInp, wsIn.Rows(rFnd.Row)).Value
            End If
            rOut.Resize(1, 7).Value = vOut 'print values to sheet
            Set rOut = rOut.Offset(1, 0) ' set to next row
            
        End If
    Next wsIn
    
    'format table
    Set rOut = rOut.Offset(-1, 0).CurrentRegion
    FormatSumTbl rOut
    
CleanUp:
    Set wsIn = Nothing
    Set wsSum = Nothing
    Set rOut = Nothing
    Set rInp = Nothing
    Set rFnd = Nothing
    Set rSrch = Nothing
    
End Sub




Sub FormatSumTbl(rTbl As Range)
'
' FormatSumTbl Macro
' Format the Summary Table & headings
'


'
    With rTbl
        .HorizontalAlignment = xlCenter
        .NumberFormat = "0.0"
        .Borders(xlDiagonalDown).LineStyle = xlNone
        .Borders(xlDiagonalUp).LineStyle = xlNone
        With .Borders(xlEdgeLeft)
            .LineStyle = xlContinuous
            .ColorIndex = 0
            .TintAndShade = 0
            .Weight = xlMedium
        End With
        With .Borders(xlEdgeTop)
            .LineStyle = xlContinuous
            .ColorIndex = 0
            .TintAndShade = 0
            .Weight = xlMedium
        End With
        With .Borders(xlEdgeBottom)
            .LineStyle = xlContinuous
            .ColorIndex = 0
            .TintAndShade = 0
            .Weight = xlMedium
        End With
        With .Borders(xlEdgeRight)
            .LineStyle = xlContinuous
            .ColorIndex = 0
            .TintAndShade = 0
            .Weight = xlMedium
        End With
        With .Borders(xlInsideVertical)
            .LineStyle = xlContinuous
            .ColorIndex = 0
            .TintAndShade = 0
            .Weight = xlThin
        End With
        With .Borders(xlInsideHorizontal)
            .LineStyle = xlContinuous
            .ColorIndex = 0
            .TintAndShade = 0
            .Weight = xlThin
        End With
        With .Columns(1)
            .Borders(xlInsideHorizontal).LineStyle = xlNone
            .EntireColumn.AutoFit
            With .Font
                .Color = -16776961
                .TintAndShade = 0
            End With
        End With
        With .Rows(1)
            .Font.Underline = xlUnderlineStyleSingle
        End With
        With .Columns(2)
            .Font.Bold = True
            .Font.Underline = xlNone
        End With
        With Cells(1, 2).Font
            .Color = -16776961
            .TintAndShade = 0
        End With
    End With
End Sub
This should do the trick on a single workbook. Try it on an example workbook) like the one you posted)
Read the comments to see what and how it works, and what you need to modify ( like the two constants possibly) for your real workbooks.

The user only needs to select the first cell of the column to be processed. The cells above it are ignored, as is the summary row at the bottom.