VBA Cutsom function breaks on updating another workbook

PanzerRanger

New Member
Joined
Jan 3, 2018
Messages
20
Hi!

I have write a custom function sista raden means last row:

Public Function SISTARADEN()
Dim a, h As Integer
a = Worksheets("Stl").Cells(Rows.Count, "A").End(xlUp).Row - 1
h = Worksheets("Stl").Cells(Rows.Count, "H").End(xlUp).Row - 1
If a > h Then
SISTARADEN = a
Else: SISTARADEN = h
End If

End Function

It is then used in a formula =IF(SISTARADEN()/30<1;1;ROUNDUP(SISTARADEN()/30;0))
It is use to automatically create pages in another workbook. The problem is, that if I make a full calculations in another workbook this custom formulas, and a few others, similar to this breaks by returning #VALUE !

What have I done wrong? :eek:
 

FormR

MrExcel MVP
Joined
Aug 18, 2011
Messages
6,212
Office Version
365
Platform
Windows
Hi, welcome to the forum! You probably need to qualify the workbook. Assuming the UDF is in the workbook that is calling it.

Code:
Public Function SISTARADEN()
 Dim a As Long, h As Long
 a = ThisWorkbook.Worksheets("Stl").Cells(Rows.Count, "A").End(xlUp).Row - 1
 h = ThisWorkbook.Worksheets("Stl").Cells(Rows.Count, "H").End(xlUp).Row - 1
 If a > h Then
 SISTARADEN = a
 Else: SISTARADEN = h
 End If
End Function
But, in my opinion, you should really be passing the ranges to the function, so..

Code:
Public Function SISTARADEN(Col1 As Range, Col2 As Range)
 Dim a As Long, h As Long
 a = Col1.Cells(Rows.Count, "A").End(xlUp).Row - 1
 h = Col2.Cells(Rows.Count, "H").End(xlUp).Row - 1
 If a > h Then
 SISTARADEN = a
 Else: SISTARADEN = h
 End If
End Function
Which you would call like:
=IF(SISTARADEN(stl!A:A;stl!H:H)/30<1;1;ROUNDUP(SISTARADEN(stl!A:A;stl!H:H)/30;0))

Note the changes to the variable declarations.
 
Last edited:

FormR

MrExcel MVP
Joined
Aug 18, 2011
Messages
6,212
Office Version
365
Platform
Windows
But, in my opinion, you should really be passing the ranges to the function, so..
That second piece of code was a last minute addition to my post and should you opt for that option this would be better:

Code:
Public Function SISTARADEN(Col1 As Range, Col2 As Range)
 Dim a As Long, h As Long
 a = Col1.Cells(Col1.Rows.Count).End(xlUp).Row - 1
 h = Col2.Cells(Col2.Rows.Count).End(xlUp).Row - 1
 If a > h Then
 SISTARADEN = a
 Else: SISTARADEN = h
 End If
End Function
 
Last edited:

Forum statistics

Threads
1,081,421
Messages
5,358,584
Members
400,505
Latest member
JacquiT

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