Automated Percentile VBA Code

gabe

New Member
Joined
Jul 30, 2008
Messages
33
So basically I have a column of numbers. I need to calculate the 25th, 50th, 75th, and 90th percentiles automatically. There is one blank row between the bottom of the column and my 25th percentile calculation. The VBA code below would work if the column was a fixed number of rows but there could be anywhere from 10-100+ rows. Does anyone know how to change the code so that it will find the first blank row and the last blank row and include all the data in between within the percentile calc. I know this should be easy for someone with experience modifying and creating code but I haven't been able to work through this on my own. <?xml:namespace prefix = o ns = "urn:schemas-microsoft-com:eek:ffice:eek:ffice" /><o:p></o:p>
<o:p></o:p>
Thank You, Gabe
<o:p></o:p>
Sub Percentile()
'
' Percentile Macro
' Percentile Calc
'
'
ActiveCell.FormulaR1C1 = "=PERCENTILE(R[-8]C:R[-2]C,0.25)"
ActiveCell.Offset(1, 0).Range("A1").Select
ActiveCell.FormulaR1C1 = "=PERCENTILE(R[-9]C:R[-3]C,0.5)"
ActiveCell.Offset(1, 0).Range("A1").Select
ActiveCell.FormulaR1C1 = "=PERCENTILE(R[-10]C:R[-4]C,0.75)"
ActiveCell.Offset(1, 0).Range("A1").Select
ActiveCell.FormulaR1C1 = "=PERCENTILE(R[-11]C:R[-5]C,0.9)"
ActiveCell.Offset(1, 0).Range("A1").Select
End Sub
 

Andrew Poulsom

MrExcel MVP
Joined
Jul 21, 2002
Messages
73,092
Make the starting row absolute, eg:

Rich (BB code):
ActiveCell.FormulaR1C1 = "=PERCENTILE(R1C:R[-2]C,0.25)"
 

gabe

New Member
Joined
Jul 30, 2008
Messages
33
That helped but it didn't quite do what I was looking for. Below is the updated code that I just created. What I need to do is find the first and last blank row in my column and include all the data in between. What this code does is pull all the data above my starting row.

Sub Percentile2()
'
' Percentile Macro
' Percentile Calc
'
'
ActiveCell.FormulaR1C1 = "=PERCENTILE(R1C:R[-2]C,0.25)"
ActiveCell.Offset(1, 0).Range("A1").Select
ActiveCell.FormulaR1C1 = "=PERCENTILE(R1C:R[-3]C,0.5)"
ActiveCell.Offset(1, 0).Range("A1").Select
ActiveCell.FormulaR1C1 = "=PERCENTILE(R1C:R[-4]C,0.75)"
ActiveCell.Offset(1, 0).Range("A1").Select
ActiveCell.FormulaR1C1 = "=PERCENTILE(R1C:R[-5]C,0.9)"
ActiveCell.Offset(1, 0).Range("A1").Select
End Sub
 

Andrew Poulsom

MrExcel MVP
Joined
Jul 21, 2002
Messages
73,092
Try:

Code:
Sub Percentile2()
' Percentile Macro
' Percentile Calc
    Dim FirstRow As Long
    With ActiveCell
        FirstRow = .Offset(-2).End(xlUp).Row
            .FormulaR1C1 = "=PERCENTILE(R" & FirstRow & "C:R[-2]C,0.25)"
            .Offset(1, 0).FormulaR1C1 = "=PERCENTILE(R" & FirstRow & "C:R[-3]C,0.5)"
            .Offset(2, 0).FormulaR1C1 = "=PERCENTILE(R" & FirstRow & "C:R[-4]C,0.75)"
            .Offset(3, 0).FormulaR1C1 = "=PERCENTILE(R" & FirstRow & "C:R[-5]C,0.9)"
    End With
End Sub
 

Forum statistics

Threads
1,081,693
Messages
5,360,658
Members
400,592
Latest member
katekoz

Some videos you may like

This Week's Hot Topics

  • VBA (Userform)
    Hi All, I just would like to know why my code isn't working. Here is my VBA code: [CODE=vba]Private Sub OKButton_Click() Dim i As Integer...
  • List box that changes fill color
    Hello, I have gone through so many pages trying to figure this out. I have a 2020 calendar that depending on the day needs to have a certain...
  • Remove duplicates and retain one. Cross-linked cases
    Hi all I ran out of google keywords to use and still couldn't find a reference how to achieve the results of a single count. It would be great if...
  • VBA Copy and Paste With Duplicates
    Hello All, I'm in need of some input. My VBA skills are sub-par at best. I've assembled this code from basic research and it works but is...
  • Macro
    is it possible for a macro to run if the active cell value is different to the value above it
  • IF DATE and TIME
    I currently use this to check if date has passed but i also need to set a time on it too. Is it possible? [CODE=vba]=IF(B:B>TODAY(),"Not...
Top