Macro for max and min in a continuous range of values

Vbalearner85

Board Regular
Joined
Jun 9, 2019
Messages
139
Office Version
  1. 2016
Platform
  1. Windows
Hi,
I have 2 columns(col A and B) continuous data in a sheet "Analysis" as below.

Column A has value either of N, L and H is consecutive until it changes to other 2 options. Each value in column A has numerical value against it (either negative ,0, or Positive numerical value)

I wanted to get output as max and min for each value of continuous range of column A. so for below data output should be

Output

Value Min Max

N -1 5
L -2.5 6
H -3.7 7
L -2.3 1.2 and so on.....for below data

Data
Column A
Column B

N 1
N 2
N -1
N 5
L 6
L -2.5
H -3.7
H 7
H 4.5
L -2.3
L 1.2
and so on....






and so on....
 

Excel Facts

Easy bullets in Excel
If you have a numeric keypad, press Alt+7 on numeric keypad to type a bullet in Excel.
How about:

VBA Code:
Sub MaxandMin()

Dim firstrow As Long
Dim lastrow As Long
Dim myrange As Range
Dim outrow As Long

firstrow = 2
outrow = 2
Cells(1, 4) = "Value"
Cells(1, 5) = "Min"
Cells(1, 6) = "Max"


Do Until Cells(firstrow, 1) = ""
lastrow = firstrow
    Do Until Cells(lastrow, 1) <> Cells(lastrow + 1, 1)
    lastrow = lastrow + 1
    Loop
Set myrange = Range(Cells(firstrow, 2), Cells(lastrow, 2))
Cells(outrow, 4) = Cells(lastrow, 1)
Cells(outrow, 5) = Application.WorksheetFunction.Min(myrange)
Cells(outrow, 6) = Application.WorksheetFunction.Max(myrange)
firstrow = lastrow + 1
outrow = outrow + 1
Loop

End Sub
 
Upvote 0
Awesome sir....Macros and macros experts ...often amaze me and I admire them.....works great.as I wanted. ...Many Thanks

One small customization request....if we have time value in column C...need max for that as well similar to column B (time format is hh:mm:ss)....and also how can we above macro to all sheets in the workbook at once.....
Regards..PK
 
Upvote 0
Hi sir...can't edit above as 10 mins past.....relooked at my needs..

Updated customization request....
1) Data has row data record time in format (mm-dd-yyyy hh:mm:ss) in column C...need record time for 1st occurrence of N/L/H for each instance (will be 1st row corresponding to each repeated instance of N/L/H)
2) Data also has Time Elapsed-Timer (since start of each instance of N/L/H (in format hh:mm:ss) in column D (will be last row corresponding to each repeated instance of N/L/H)
3) how can we apply above macro to all sheets in the workbook at once.....

Regards,
PK
 
Upvote 0
If I understand you correctly, try:

VBA Code:
Sub MaxandMin()

Dim firstrow As Long
Dim lastrow As Long
Dim myrange As Range
Dim outrow As Long
Dim myws As Worksheet

For Each myws In Worksheets

firstrow = 2
outrow = 2
myws.Cells(1, 4) = "Value"
myws.Cells(1, 5) = "Min"
myws.Cells(1, 6) = "Max"
myws.Cells(1, 7) = "Start"
myws.Cells(1, 8) = "Finish"

Do Until myws.Cells(firstrow, 1) = ""
lastrow = firstrow
    Do Until myws.Cells(lastrow, 1) <> myws.Cells(lastrow + 1, 1)
    lastrow = lastrow + 1
    Loop
Set myrange = myws.Range(myws.Cells(firstrow, 2), myws.Cells(lastrow, 2))
myws.Cells(outrow, 4) = myws.Cells(lastrow, 1)
myws.Cells(outrow, 5) = Application.WorksheetFunction.Min(myrange)
myws.Cells(outrow, 6) = Application.WorksheetFunction.Max(myrange)
myws.Cells(outrow, 7) = myws.Cells(firstrow, 2)
myws.Cells(outrow, 8) = myws.Cells(lastrow, 2)
firstrow = lastrow + 1
outrow = outrow + 1
Loop

Next

End Sub
 
Upvote 0
Solution

Forum statistics

Threads
1,213,497
Messages
6,113,998
Members
448,541
Latest member
iparraguirre89

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top