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
 

RoryA

MrExcel MVP, Moderator
Joined
May 2, 2008
Messages
34,323
Office Version
365, 2019, 2016, 2010
Platform
Windows, MacOS
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.
 

kuroba

New Member
Joined
Nov 9, 2015
Messages
16
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.
 

Forum statistics

Threads
1,081,708
Messages
5,360,777
Members
400,595
Latest member
T_Dubs

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