+ Reply to Thread
Results 1 to 18 of 18

Message box macro not working

Hybrid View

scottwhittaker2333 Message box macro not working 06-11-2010, 06:19 PM
Deamo Re: Message box macro not... 06-11-2010, 07:06 PM
davesexcel Re: Message box macro not... 06-11-2010, 07:26 PM
Marcol Re: Message box macro not... 06-11-2010, 07:42 PM
shg Re: Message box macro not... 06-11-2010, 08:14 PM
scottwhittaker2333 Re: Message box macro not... 06-11-2010, 08:47 PM
Marcol Re: Message box macro not... 06-11-2010, 09:02 PM
shg Re: Message box macro not... 06-11-2010, 09:35 PM
Marcol Re: Message box macro not... 06-11-2010, 09:51 PM
scottwhittaker2333 Re: Message box macro not... 06-11-2010, 11:00 PM
Marcol Re: Message box macro not... 06-12-2010, 05:50 AM
davesexcel Re: Message box macro not... 06-12-2010, 09:44 AM
Marcol Re: Message box macro not... 06-12-2010, 10:22 AM
scottwhittaker2333 Re: Message box macro not... 06-12-2010, 02:13 PM
scottwhittaker2333 Re: Message box macro not... 06-12-2010, 06:24 PM
shg Re: Message box macro not... 06-12-2010, 06:42 PM
  1. #1
    Registered User
    Join Date
    06-02-2010
    Location
    Grand Rapids, Michigan
    MS-Off Ver
    Excel 2003
    Posts
    64

    Smile Message box macro not working

    I have the following code that I want to have a message box pop up if the value of cell H104 is more or less than the value of cell F104 by more than 0.02. I have been playing with this code for about 3 days now but can't seem to get it to work. Any Ideas?

    Private Sub Workbook_SheetChange(ByVal Sh As Object, ByVal Target As Range)
    Dim Cell As Range
    If Application.Intersect(Target, Range("H104")) Is Nothing Then Exit Sub
    For Each Cell In Range("H104")    
    If (Cell.Value < (Range("F104").Value - 0.02)) Then
           MsgBox "SCALE CHECK 1 HAS FAILED CALIBRATION AND MUST BE RECALIBRATED BEFORE IT CAN BE USED TO TAKE WEIGHTS"
                 Exit Sub
            End If
         Next Cell
     If Application.Intersect(Target, Range("H104")) Is Nothing Then Exit Sub
      For Each Cell In Range("H104")  
     If (Cell.Value > (Range("F104").Value + 0.02)) Then
           MsgBox "SCALE check 1 HAS FAILED CALIBRATION AND MUST BE RECALIBRATED BEFORE IT CAN BE USED TO TAKE WEIGHTS"
                  Exit Sub
            End If
    Next Cell
    End Sub
    Last edited by scottwhittaker2333; 06-12-2010 at 07:08 PM.

  2. #2
    Registered User
    Join Date
    04-14-2010
    Location
    NZ
    MS-Off Ver
    2007,2010
    Posts
    86

    Re: Message box macro not working

    I'm not sure why you have a for loop running on one cell?

    replace you code with this..

    If Intersect(Target, Range("D8")) Is Nothing Then Exit Sub
    If (Range("D8").Value < Range("F8").Value - 0.02) Or (Range("D8").Value > Range("F8").Value + 0.02) Then
           MsgBox "SCALE CHECK 1 HAS FAILED CALIBRATION AND MUST BE RECALIBRATED BEFORE IT CAN BE USED TO TAKE WEIGHTS"
                 Exit Sub
    End If

  3. #3
    Forum Moderator davesexcel's Avatar
    Join Date
    02-19-2006
    Location
    Regina
    MS-Off Ver
    MS 365
    Posts
    13,524

    Re: Message box macro not working

    Private Sub Worksheet_Change(ByVal Target As Range)
        Dim c As Range
        Set c = Range("F104")
        If Target.Count > 1 Then Exit Sub
        If Target.Address = "$H$104" Then
            If Target - c > 0.02009 Or Target - c < -0.02009 Then
                MsgBox "Do something else"
            End If
        End If
    End Sub

  4. #4
    Forum Guru (RIP) Marcol's Avatar
    Join Date
    12-23-2009
    Location
    Fife, Scotland
    MS-Off Ver
    Excel '97 & 2003/7
    Posts
    7,216

    Re: Message box macro not working

    Or possibly.......?
    Private Sub Workbook_SheetChange(ByVal Sh As Object, ByVal Target As Range)
        
        If Target.Address <> "$H$104" Then Exit Sub
        
        Select Case Target
            Case Is > Range("F104") + 0.02, Is < Range("F104").Value - 0.02
                MsgBox "SCALE CHECK 1 HAS FAILED CALIBRATION AND MUST BE RECALIBRATED BEFORE IT CAN BE USED TO TAKE WEIGHTS", vbCritical
            Case Else
                MsgBox "SCALE CHECK 1 PASSED", vbInformation
        End Select
        
    End Sub

    [EDIT]

    I think it was how you defined your tolerances that was causing the problem.
    This code should be okay now.

    Hope this helps.

    If you need any further information, please feel free to ask further

    However

    If this takes care of your needs, please click EDIT in your original post, click GO ADVANCED and set the PREFIX box to SOLVED. It helps everybody!
    Also
    If you are satisfied by any members response to your problem please consider using the scales icon top right of thier post to show your appreciation.
    Last edited by Marcol; 06-11-2010 at 08:09 PM. Reason: Tolerances corrected

  5. #5
    Forum Expert shg's Avatar
    Join Date
    06-20-2007
    Location
    The Great State of Texas
    MS-Off Ver
    2010, 2019
    Posts
    40,689

    Re: Message box macro not working

    Or ...
    Private Sub Workbook_SheetChange(ByVal Sh As Object, ByVal Target As Range)
        If Target.Address <> "$H$104" Then Exit Sub
        
        If Abs(Target.Value - Me.Range("F104").Value) <= 0.02 Then
            MsgBox "All good", vbInformation
        Else
            MsgBox "Not so good", vbCritical
        End Select
    End Sub
    Entia non sunt multiplicanda sine necessitate

  6. #6
    Registered User
    Join Date
    06-02-2010
    Location
    Grand Rapids, Michigan
    MS-Off Ver
    Excel 2003
    Posts
    64

    Re: Message box macro not working

    Ihave tested all of the above posts and none of them did anything. The las one returned some error so I changed it to this, however that did not work either.
     Private Sub Workbook_SheetChange(ByVal Target As Range, ByVal Target As Range)
    If Target.Address <> "$H$104" Then Exit Sub
        
        If Abs(Target.Value - Range("F104").Value) <= 0.02 Then
            MsgBox "All good", vbInformation
        Else
            MsgBox "Not so good", vbCritical
        End If
    
    
    End Sub
    I really am at a loss for why this isn't working. I have several other codes that are almost Identical to the code in my first post and they work fine.

  7. #7
    Forum Guru (RIP) Marcol's Avatar
    Join Date
    12-23-2009
    Location
    Fife, Scotland
    MS-Off Ver
    Excel '97 & 2003/7
    Posts
    7,216

    Re: Message box macro not working

    Where are you putting the code?


    Demo workbook attached

    [EDIT]
    Code amended to allow for Delete

    Private Sub Workbook_SheetChange(ByVal Sh As Object, ByVal Target As Range)
        
        If Target.Address <> "$H$104" Then Exit Sub
        If Target = "" Then Exit Sub
        
        Select Case Target
            Case Is > Range("F104") + 0.02, Is < Range("F104").Value - 0.02
                MsgBox "SCALE CHECK 1 HAS FAILED CALIBRATION AND MUST BE RECALIBRATED BEFORE IT CAN BE USED TO TAKE WEIGHTS", vbCritical
            Case Else
                If Target <> "" Then MsgBox "SCALE CHECK 1 PASSED", vbInformation
        End Select
        
    End Sub

    Attachment updated

    [EDIT]
    See shgs' post #8

    If the code is in the module ThisWorkbook

    Then it will work as it stands in any sheet in the workbook.

    If you only want it to apply to a specific sheet then the code must go in the module for that sheet.

    Thanks shg
    Attached Files Attached Files
    Last edited by Marcol; 06-11-2010 at 09:49 PM. Reason: Added demo workbook, trouble attaching file

  8. #8
    Forum Expert shg's Avatar
    Join Date
    06-20-2007
    Location
    The Great State of Texas
    MS-Off Ver
    2010, 2019
    Posts
    40,689

    Re: Message box macro not working

    The Workbook_SheetChange event has to go in ThisWorkbook.

    If you change the signature to
    Private Sub Worksheet_Change(ByVal Target As Range)
    ... then it goes in the Sheet module.

  9. #9
    Forum Guru (RIP) Marcol's Avatar
    Join Date
    12-23-2009
    Location
    Fife, Scotland
    MS-Off Ver
    Excel '97 & 2003/7
    Posts
    7,216

    Re: Message box macro not working

    My oversight shg

    Apologies

    Post amended to suit

  10. #10
    Registered User
    Join Date
    06-02-2010
    Location
    Grand Rapids, Michigan
    MS-Off Ver
    Excel 2003
    Posts
    64

    Re: Message box macro not working

    Thanks for the assistance and I realize that the code is for the workbook and thats were it is. There must be something else that is causing the macro to not work. It is in the workbook_sheetchange and in the correct location but it is there with many other macros I wonder if that has something to do with it. I know that if there is to much it will say pocerdure to large and I have not gotten that worning so I do not think thats it. I will attach a copy of what I am using and you can take a look at that. Maybe you will see what I am missing. As I said there is alot of code in the workbook so scroll all the way to the bottom and you will see your code not working.
    Attached Files Attached Files

  11. #11
    Forum Guru (RIP) Marcol's Avatar
    Join Date
    12-23-2009
    Location
    Fife, Scotland
    MS-Off Ver
    Excel '97 & 2003/7
    Posts
    7,216

    Re: Message box macro not working

    hmmm ......

    At first glance your code is somewhat over complicated, the continual use of
    Exit Sub
    means in all probability the sub has done just that before it gets to the code you are trying to add.

    How much off your code actually comes into use? I suspect there will be other chunks that are not triggered.

    Try putting the new code at the beginning of your code to see what I mean, then only it will work!!!!

    You need at the very the least to use If > ElseIf > Else statements, or better still Select Case.

    Are there other sheets in the workbook, if so the code you are using is triggered on every one!
    I again am only guessing at this stage, but I think the Sheet_Change is a better place for your code.

    Why do you have
    Sub Workbook_BeforeClose(Cancel As Boolean)
    in a stndard module, Module3, and not in the module ThisWorkbook ?

    I'll have a further look later, but this will take some time to sort out.


    [EDIT]

    Why so many merged cells?
    They are a major source of problems in my opinion
    Last edited by Marcol; 06-12-2010 at 06:20 AM.

  12. #12
    Forum Moderator davesexcel's Avatar
    Join Date
    02-19-2006
    Location
    Regina
    MS-Off Ver
    MS 365
    Posts
    13,524

    Re: Message box macro not working

    I just placed SHG's code in the worksheet module, and it worked fine

    Private Sub Worksheet_Change(ByVal Target As Range)
         If Target.Address <> "$H$104" Then Exit Sub
    
        If Abs(Target.Value - Me.Range("F104").Value) <= 0.02 Then: MsgBox "All good", vbInformation: Else: MsgBox "Not so good", vbCritical
    
    End Sub
    Last edited by davesexcel; 06-12-2010 at 09:52 AM.

  13. #13
    Forum Guru (RIP) Marcol's Avatar
    Join Date
    12-23-2009
    Location
    Fife, Scotland
    MS-Off Ver
    Excel '97 & 2003/7
    Posts
    7,216

    Re: Message box macro not working

    They all do!

    The problem seems to be the amount of unneeded code, esp Exit Sub
    The code has been inserted at the end of the procedure and is is being exited before it is triggered, due to other events being triggered with the change event.

    Scott
    Do you really need so many cells checked and changed if only one cell is changing?
    This will slow excel down considerably.

    Put the chosen code at the beginning and modify the conditions to trigger it and all is okay

        If Target.Address = "$H$104" Then
            If Target = "" Then Exit Sub
            
            Select Case Target
                Case Is > Range("F104") + 0.02, Is < Range("F104").Value - 0.02
                    MsgBox "SCALE CHECK 1 HAS FAILED CALIBRATION AND MUST BE RECALIBRATED BEFORE IT CAN BE USED TO TAKE WEIGHTS", vbCritical
                Case Else
                    MsgBox "SCALE CHECK 1 PASSED", vbInformation
            End Select
            Exit Sub
        End If

    What are the tolerances required in L104,P104,T104 & X104?
    I suspect the will use the same or similar code to H104


    Amended workbook attached.

    I'm trimming some of the code in another copy of the file and will post it later.

    I hope this helps in the meantime.
    Attached Files Attached Files
    Last edited by Marcol; 06-12-2010 at 10:32 AM. Reason: Question on tolerances added

  14. #14
    Registered User
    Join Date
    06-02-2010
    Location
    Grand Rapids, Michigan
    MS-Off Ver
    Excel 2003
    Posts
    64

    Re: Message box macro not working

    I am confused. I opened the workbook you attached and the scale calibration macro still didn't do anything even though it was at the top of the code. Did it work for you?
    As for the other codes in the workbook they all seem to work just fine for me. I have noticed that it runs quite a bit slower when I do it at home thought. Excel 2002 at work and 2007 at home. May be a compatibility mode issue. Weight checks are done in sets of 5 every hour and each set lives and dies together. Unfortunatly the cells do have to be merged. One of the conditions for the project was that I had to keep the format of our paper version.
    It was actually what I used for the starting point.
    I have to say that when I started the project I didn't know anything about macros and have been studying lots of forums and using a visual basic ref guide to learn about them. I've been working on this for about a month now and have learned alot but still have a ways to go. I have to admit that I actually enjoy learning about excel macros, however sometimes it can be a little frustrating. No one at work seems to have a clue about macros. Believe me I asked. What other code can be removed? I already did quite a bit of trimming as alot of the code was recorded to start. Oh and the before close thing in the model is actually not needed. It was origenally part of the workbook code but I didn't want to delete it so I put it in a model for later use.
    Also I wasn't aware that the exit subs could be removed. All of the 40 weight failure macros have it and they function fine so I do not understand why another one at the end would not work. If the Exit sub was causing the problem wouldn't most of the other codes also not work?

  15. #15
    Registered User
    Join Date
    06-02-2010
    Location
    Grand Rapids, Michigan
    MS-Off Ver
    Excel 2003
    Posts
    64

    Re: Message box macro not working

    It seems that there really is to much code in the workbook.'I put all of the codes in the worksheet_Change in code for worksheet and they all seemed to work. I ended up going with this code for now.
    Private Sub Worksheet_Change(ByVal Target As Range)
    
     If Application.Intersect(Target, Union(Range("H104"), Range("L104"), Range("P104"), Range("T104"), Range("X104"))) Is Nothing Then Exit Sub
           If Range("H104").Value < Range("F104").Value - 0.02 Or Range("H104").Value > Range("F104").Value + 0.02 Then
           MsgBox "SCALE Check 1 HAS FAILED CALIBRATION AND MUST BE RECALIBRATED BEFORE IT CAN BE USED TO TAKE WEIGHTS"
           End If
           If Range("L104").Value < Range("J104").Value - 0.02 Or Range("L104").Value > Range("J104").Value + 0.02 Then
           MsgBox "SCALE Check 2 HAS FAILED CALIBRATION AND MUST BE RECALIBRATED BEFORE IT CAN BE USED TO TAKE WEIGHTS"
           End If
           If Range("P104").Value < Range("N104").Value - 0.02 Or Range("P104").Value > Range("N104").Value + 0.02 Then
           MsgBox "SCALE Check 3 HAS FAILED CALIBRATION AND MUST BE RECALIBRATED BEFORE IT CAN BE USED TO TAKE WEIGHTS"
           End If
           If Range("T104").Value < Range("R104").Value - 0.02 Or Range("T104").Value > Range("R104").Value + 0.02 Then
           MsgBox "SCALE Check 4 HAS FAILED CALIBRATION AND MUST BE RECALIBRATED BEFORE IT CAN BE USED TO TAKE WEIGHTS"
           End If
           If Range("X104").Value < Range("V104").Value - 0.02 Or Range("X104").Value > Range("V104").Value + 0.02 Then
           MsgBox "SCALE Check 5 HAS FAILED CALIBRATION AND MUST BE RECALIBRATED BEFORE IT CAN BE USED TO TAKE WEIGHTS"
           End If
               
    End Sub
    I'm still not really sure why its not working in the workbook as I removed all the exit subs and did not get the procedure to large worning but it still would not work when I copied and pasted it there. One thing i've learned there are alot of different ways to write code to get the same end result. And alot of it seems to be personal prefrence. Thanks to everyone for there assistance. You have all been very helpful.
    Last edited by scottwhittaker2333; 06-12-2010 at 06:29 PM.

  16. #16
    Forum Expert shg's Avatar
    Join Date
    06-20-2007
    Location
    The Great State of Texas
    MS-Off Ver
    2010, 2019
    Posts
    40,689

    Re: Message box macro not working

    Another way:
    Private Sub Worksheet_Change(ByVal Target As Range)
        Dim cell        As Range
        Dim i           As Long
    
        With Range("H104, L104, P104, T104, X104")
            If Application.Intersect(Target, .Cells) Is Nothing Then Exit Sub
            For Each cell In .Cells
                i = i + 1
                If Abs(Target.Value - Target.Offset(, -2).Value) > 0.02 Then
                    MsgBox "SCALE Check " & i & " HAS FAILED CALIBRATION AND MUST BE RECALIBRATED BEFORE IT CAN BE USED TO TAKE WEIGHTS"
                End If
            Next cell
        End With
    End Sub

  17. #17
    Registered User
    Join Date
    06-02-2010
    Location
    Grand Rapids, Michigan
    MS-Off Ver
    Excel 2003
    Posts
    64

    Re: Message box macro not working

    Thanks shg but when I ran the code I got a type mismatch error on this part
    If Abs(Target.Value - Target.Offset(, -2).Value) > 0.02 Then

+ Reply to Thread

Thread Information

Users Browsing this Thread

There are currently 1 users browsing this thread. (0 members and 1 guests)

Tags for this Thread

Bookmarks

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts

Search Engine Friendly URLs by vBSEO 3.6.0 RC 1