• Hi All

    Please note that at the Chandoo.org Forums there is Zero Tolerance to Spam

    Post Spam and you Will Be Deleted as a User

    Hui...

  • When starting a new post, to receive a quicker and more targeted answer, Please include a sample file in the initial post.

Excel VBA real time UserForm Labels from Workbook cells

mrwad

New Member
I have userform called "DisplaySummaryForm" that meant to display live information about project being calculated. I have Labels to display values from worksheet cells. Now I have to reopen UserForm all the time to get my values updated or press Refresh button on userform. How they can be updated all the time? So they are so called "real time" in opened UserForm?
Button for opening UserForm:
Code:
Sub DisplaySummary()
DisplaySummaryForm.Show vbModless
End Sub
UserForm code:
Code:
Private Sub CommandButton1_Click()
Unload Me
End Sub
Private Sub UserForm_Initialize()
Controls("Label11").Caption = ThisWorkbook.Sheets("MAIN").Range("D11").value
Controls("Label12").Caption = ThisWorkbook.Sheets("MAIN").Range("D14").value
Me.TextBox2.value = ThisWorkbook.Sheets("Price calculation").Range("I148").value
Controls("Label14").Caption = ThisWorkbook.Sheets("Price calculation").Range("Q148").value
Controls("Label15").Caption = ThisWorkbook.Sheets("Price calculation").Range("Q148").value
Controls("Label18").Caption = ThisWorkbook.Sheets("Price calculation").Range("Q148").value
Controls("Label16").Caption = ThisWorkbook.Sheets("Price calculation").Range("Q148").value
Controls("Label17").Caption = ThisWorkbook.Sheets("Price calculation").Range("Q148").value
Controls("Label20").Caption = ThisWorkbook.Sheets("Price calculation").Range("Q148").value
Controls("Label22").Caption = ThisWorkbook.Sheets("Price calculation").Range("Q148").value
End Sub
I know I can use something like:
Code:
Private Sub Worksheet_Change(ByVal Target As Range)
Dim KeyCells As Range
' The variable KeyCells contains the cells that will
' cause an alert when they are changed.
Set KeyCells = Range("Q148")
If Not Application.Intersect(KeyCells, Range(Target.Address)) _
       Is Nothing Then
    ' Display a message when one of the designated cells has been 
    ' changed.
    ' Place your code here.
    MsgBox "Cell " & Target.Address & " has changed."
End If
End Sub
But the problem is that I am not updating my cell Q148 "manually" but by formula. In cell Q148 I have something like =A1+A6+A7+A8*23 etc. Above Macro does not work in this case.
 
Also in your code above

Code:
If Not Application.Intersect(KeyCells, Range(Target.Address)) _
       Is Nothing Then

You will see Target is already a range as defined in the first Sub() line

hence your code can be:

Code:
If Not Application.Intersect(KeyCells, Target) Is Nothing Then
 
Thanks to everyone. I came up with this solution.

Code:
Private Sub Worksheet_Calculate()
    Dim KeyCell1 As Range
    Dim KeyCell2 As Range
    ' The variable KeyCells contains the cells that will
    ' cause an alert when they are changed.
    Set KeyCell1 = Range("Q148")
    Set KeyCell2 = Range("Q149")
    Set KeyCell3 = Range("Q150")
    Set KeyCell4 = Range("Q151")
    Set KeyCell5 = Range("Q152")
    Set KeyCell6 = Range("Q156")
        ' Display a message when one of the designated cells has been
        ' changed.
        DisplaySummaryForm.Controls("Label14").Caption = Format(KeyCell1.Value, "#,##0.00")
        DisplaySummaryForm.Controls("Label15").Caption = Format(KeyCell2.Value, "#,##0.00")
        DisplaySummaryForm.Controls("Label16").Caption = Format(KeyCell3.Value, "#,##0.00")
        DisplaySummaryForm.Controls("Label17").Caption = Format(KeyCell4.Value, "#,##0.00")
        DisplaySummaryForm.Controls("Label18").Caption = Format(KeyCell5.Value, "#,##0.00")
        DisplaySummaryForm.Controls("Label20").Caption = Format(KeyCell6.Value, "#,##0.00")
End Sub
 
You might find this handy

Code:
Private Sub Worksheet_Calculate()
  Dim i As Integer
  For i = 1 To 6
  If i = 6 Then i = 9
  DisplaySummaryForm.Controls("Label" & CStr(11 + i)).Caption = Format(Cells(147 + i, 17).Value, "#,##0.00")
  Next i
End Sub
 
Last edited:
Back
Top