Custom Function question

kuroba

New Member
Joined
Nov 9, 2015
Messages
16
Hello Guys,

I have a custom function that I created to make naming batches of work much easier (it was base on a formula that I used in excel).
The issue I'm having with it is that if any changes happen within the sheet that the function is it will work with no problem, but if I'm working on a different sheet from the one that I have the function then it does not update.

I think I know what's causing the issue, yet do not know how to approach it.


I believe that the issue is base on "WorksheetFunction.Count"

Code:
Option Explicit'This Function is to name batches base one AS400 Batch Naming Scheme
' For RBO CC batches start with a 6 follow by a letter (Example 6A)
' For Velocity CC batches start with a 7 follow by a letter (Example 7A)
' For EFT batches start with a "E" follow by a letter (Example EA)
' For Medicare batches start with a "M" follow by a letter (Example MA)
' For RDS batches start with a "S" follow by a letter (Example SA)
Function BatchName(FirstProduct As Range, CurrentProduct As Range, Optional StartBatch As String) As String
Application.Volatile
Dim Letter As String
Letter = Chr(64 + WorksheetFunction.Count(Range(CurrentProduct.Address))) 'FirstProduct.Address & ":" &
BatchName = ""
Select Case StartBatch
    Case 7
            If CurrentProduct <> "" Then BatchName = StartBatch & Letter
            If Asc(Letter) > 90 Or Left(BatchName, 1) = StartBatch + 1 Then BatchName = StartBatch + 1 & Chr(64 + WorksheetFunction.Count(Range(FirstProduct.Address & ":" & CurrentProduct.Address)) - 26)
    Case 60
            If CurrentProduct <> "" Then BatchName = StartBatch + WorksheetFunction.Count(Range(FirstProduct.Address & ":" & CurrentProduct.Address)) - 1
    Case Else
            If CurrentProduct <> "" Then BatchName = StartBatch & Chr(64 + WorksheetFunction.Count(Range(CurrentProduct.Address))) 'Letter
End Select
'Application.Calculate
End Function
 

Excel Facts

Select a hidden cell
Somehide hide payroll data in column G? Press F5. Type G1. Enter. Look in formula bar while you arrow down through G.
The issue is that you have lots of Range calls that are not qualified with a worksheet object. Try this:

Code:
Function BatchName(FirstProduct As Range, CurrentProduct As Range, Optional StartBatch As String) As String
Dim Letter As String
Dim ws As Worksheet
Application.Volatile
Set ws = FirstProduct.Worksheet
Letter = Chr(64 + WorksheetFunction.Count(CurrentProduct)) 'FirstProduct.Address & ":" &
BatchName = ""
Select Case StartBatch
    Case 7
            If CurrentProduct <> "" Then BatchName = StartBatch & Letter
            If Asc(Letter) > 90 Or Left(BatchName, 1) = StartBatch + 1 Then BatchName = StartBatch + 1 & Chr(64 + WorksheetFunction.Count(ws.Range(FirstProduct, CurrentProduct)) - 26)
    Case 60
            If CurrentProduct <> "" Then BatchName = StartBatch + WorksheetFunction.Count(ws.Range(FirstProduct, CurrentProduct)) - 1
    Case Else
            If CurrentProduct <> "" Then BatchName = StartBatch & Chr(64 + WorksheetFunction.Count(CurrentProduct)) 'Letter
End Select
'Application.Calculate
End Function

Note: it would be better if you could pass the full range to your function - then it would not have to be volatile.
 
Upvote 0
The issue is that you have lots of Range calls that are not qualified with a worksheet object. Try this:

Code:
Dim ws As Worksheet
Set ws = FirstProduct.Worksheet

Note: it would be better if you could pass the full range to your function - then it would not have to be volatile.

Thanks Rory. That worked perfectly on what i needed to do.

The reason why I didn't want to make that range set, is because if some of my coworkers are using that function they would get all mess up. So I tried to make it as simple as I could possibly do it.
 
Upvote 0

Forum statistics

Threads
1,214,397
Messages
6,119,271
Members
448,882
Latest member
Lorie1693

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