WorksheetFunction StDev error (easy?)

randomwit

New Member
Joined
Apr 2, 2010
Messages
16
'Unable to get the StDev property of the WorkSheetFunction class'

Ok guys, this error isn't too difficult (I don't think)...

I have problems with my newSTDEV function when a worksheet only has one line of entered data in it. I believe it's because you can't take StDev with only one value so the function returns something like #VALUE!. How can i make it so that the runtime error doesn't show up? If the result is a #VALUE! in the cell, that's perfectly fine.

On a side note, the function works when i enter it manually, but not when I use it through vba like in the line below. I checked my parameters and they look perfect.
Code:
StartCol.FormulaR1C1 = "=newSTDEV(R[" & dataRow & "]C:R[" & (dataRow + 1000) & "]C, 15)"



Code:
Function newSTDEV(rangeInp As Range, iCI As Long)
'This function removes all cells with the background color index iCI from rangeInp
'and returns the new range selection's standard deviation

'Inputs:
    'rangeInp: a range of cells to be checked
    'iCI: color index to search rangeInp for
'Output:
    'rOut: subrange of rangeInp with all cells that match iCI b.g. color removed
    
    Application.Volatile
    
    Dim cell As Range
    Dim rOut As Range
    
    For Each cell In rangeInp.Cells
        If cell.Interior.ColorIndex <> iCI Then
            If rOut Is Nothing Then Set rOut = cell
            Set rOut = Union(rOut, cell)
        End If
    Next cell
    
    newSTDEV = Application.WorksheetFunction.StDev(rOut)
  
End Function
 

Excel Facts

Does the VLOOKUP table have to be sorted?
No! when you are using an exact match, the VLOOKUP table can be in any order. Best-selling items at the top is actually the best.
This may be a little rough, but I would basically assign a "default" error value as the return value, and use an on error resume next statement to ensure that the code doesn't halt during execution. If the "real" standard deviation result isn't successfully entered in the cell, you'll get your plug error value instead.

Code:
    Application.Volatile
    
    [COLOR="Navy"]Dim[/COLOR] cell [COLOR="Navy"]As[/COLOR] Range
    [COLOR="Navy"]Dim[/COLOR] rOut [COLOR="Navy"]As[/COLOR] Range
    
    [COLOR="Navy"]On[/COLOR] [COLOR="Navy"]Error[/COLOR] [COLOR="Navy"]Resume[/COLOR] [COLOR="Navy"]Next[/COLOR]
    newSTDEV = CVErr(xlErrNA)
    
    [COLOR="Navy"]For[/COLOR] [COLOR="Navy"]Each[/COLOR] cell [COLOR="Navy"]In[/COLOR] rangeInp.Cells
        [COLOR="Navy"]If[/COLOR] cell.Interior.ColorIndex <> iCI [COLOR="Navy"]Then[/COLOR]
            [COLOR="Navy"]If[/COLOR] rOut [COLOR="Navy"]Is[/COLOR] [COLOR="Navy"]Nothing[/COLOR] [COLOR="Navy"]Then[/COLOR] [COLOR="Navy"]Set[/COLOR] rOut = cell
            [COLOR="Navy"]Set[/COLOR] rOut = Union(rOut, cell)
        [COLOR="Navy"]End[/COLOR] [COLOR="Navy"]If[/COLOR]
    [COLOR="Navy"]Next[/COLOR] cell
 
Upvote 0
I think that worked great...I'll do a little more testing.

Thanks for the help...I've never been keen on handling errors
 
Upvote 0

Forum statistics

Threads
1,224,602
Messages
6,179,843
Members
452,948
Latest member
UsmanAli786

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