justhumm
Structural
- May 2, 2003
- 112
I threw together this UDF (code below), based on a previous (closed) thread's discussion...
I have been running it through a XLAM add-in for a few months, now. And it's generally working the way I want it to. The only major issue I've been running into is that sometimes when switching between worksheets that contain cells that use the UDF, the UDF is not recalculating automatically when switching worksheets. For example, input UDF in cell on Worksheet1, switch to Worksheet2, do something, switch back to Worksheet (image results below)...
I have been forcing the workbook to recalculate, for the time being, but can anyone suggest a better way of dealing with it? (besides making it volatile)
Thanks!
The UDF code...
I have been running it through a XLAM add-in for a few months, now. And it's generally working the way I want it to. The only major issue I've been running into is that sometimes when switching between worksheets that contain cells that use the UDF, the UDF is not recalculating automatically when switching worksheets. For example, input UDF in cell on Worksheet1, switch to Worksheet2, do something, switch back to Worksheet (image results below)...
I have been forcing the workbook to recalculate, for the time being, but can anyone suggest a better way of dealing with it? (besides making it volatile)
Thanks!


Code:
'Callback for customButton1 onAction
Sub Macro1(control As IRibbonControl)
' as of March 2018, the AddrToVal UDF sometimes needs to be kickstarted
' .ForceFullCalculation is the rough equivalent of Ctrl + Alt + Shift + F9
' [URL unfurl="true"]https://fastexcel.wordpress.com/2015/05/19/excel-forcefullcalculation-trading-off-editing-speed-vs-calculation-speed/[/URL]
ActiveWorkbook.ForceFullCalculation = _
Not (ActiveWorkbook.ForceFullCalculation)
Application.Calculate
ActiveWorkbook.ForceFullCalculation = _
Not (ActiveWorkbook.ForceFullCalculation)
End Sub
The UDF code...
Code:
Option Explicit 'Require that all variables are explicitly defined.
Public Function AddrToVal(rCell As Range) As String
'==================================================================
' This UDF is similar to the standard Excel FORMULATEXT() function,
' but it displays the cell values/contents instead of the cell address
'==================================================================
' USE / CELL ENTRY
' =AddrToVal(cell address)
'==================================================================
'Application.Volatile
Dim i As Integer, p1 As Integer, p2 As Integer
Dim Form As String, eval As String
Dim r As Range
Form = rCell.Formula
Form = Replace(Form, "$", "")
AddrToVal = "="
p1 = 2
For i = 2 To Len(Form)
Select Case Mid(Form, i, 1)
'Case "(", ")", ",", "+", "-", "*", "/", ":", "&", "^"
Case "'*'!", "(", ")", ",", "+", "-", "*", "/", ":", "&", "^"
GoSub Evaluate
End Select
Next
GoSub Evaluate
Exit Function
Evaluate:
p2 = i - 1
eval = Mid(Form, p1, p2 - p1 + 1)
On Error Resume Next
Set r = Range(eval)
If Err.Number = 0 Then
'AddrToVal = AddrToVal & Range(eval).Value & Mid(Form, i, 1)
AddrToVal = AddrToVal & Range(eval).Text & Mid(Form, i, 1)
Else
AddrToVal = AddrToVal & eval & Mid(Form, i, 1)
Err.Clear
End If
On Error GoTo 0
p1 = i + 1
Return
End Function