OnEntry Macro to Create a Running Total

Article translations Article translations
Article ID: 123578 - View products that this article applies to.
This article was previously published under Q123578
This article has been archived. It is offered "as is" and will no longer be updated.
For a Microsoft Excel 2000 version of this article, see 213445.
Expand all | Collapse all

On This Page

Summary

In Microsoft Excel, you can avoid circular references when you create a running total in a cell, by storing the result in a non-calculating part of a worksheet. This article contains sample code procedures that do this by storing a running total in a cell note, or comment (in Excel 97 and Excel 98).

More information

Microsoft provides programming examples for illustration only, without warranty either expressed or implied. This includes, but is not limited to, the implied warranties of merchantability or fitness for a particular purpose. This article assumes that you are familiar with the programming language that is being demonstrated and with the tools that are used to create and to debug procedures. Microsoft support engineers can help explain the functionality of a particular procedure, but they will not modify these examples to provide added functionality or construct procedures to meet your specific requirements.

To Create a Running Total in a Cell

  1. Enter the macro that applies to your version of Microsoft Excel.

    Excel 97 and Excel 98

    1. Start the Visual Basic Editor (press ALT+F11).
    2. On the Insert menu click Module.

      This inserts a module into your project.
    3. Type the macros following step d into this module.
    4. After typing the macros, click "Close and Return to Microsoft Excel" on the File menu.
       ' The Auto_Open name forces this macro to run every time
       ' the workbook containing this macro is opened.
    
       Sub Auto_Open()
       '  Every time a cell's value is changed,
       '  the RunningTotal macro runs.
          Application.OnEntry = "RunningTotal"
       End Sub
    
       '----------------------------------------------------------
       ' This macro runs each time the value of a cell changes.
       ' It adds the current value of the cell to the value of the
       ' cell comment. Then it stores the new total in the cell comment.
       Sub RunningTotal()
    
       On Error GoTo errorhandler      ' Skip cells that have no comment.
    
          With Application.Caller
    
       '     Checks to see if the cell is a running total by
       '     checking to see if the first 4 characters of the cell
       '     comment are "RT= ". NOTE: there is a space after the equal
       '     sign.
             If Left(.Comment.Text, 4) = "RT= " Then
    
       '        Change the cell's value to the new value in the cell
       '        plus the old total stored in the cell comment.
                RT = .Value + Right(.Comment.Text, Len(.Comment.Text) - 4)
                .Value = RT
    
       '        Store the new total in the cell note.
                .Comment.Text Text:="RT= " & RT
            End If
          End With
    
          Exit Sub      ' Skip over the errorhandler routine.
    
          errorhandler: ' End the procedure if no comment in the cell.
          Exit Sub
    
       End Sub
    
       '--------------------------------------------------------------
       ' This macro sets up a cell to be a running total cell.
       Sub SetComment()
          With ActiveCell
       '     Set comment to indicate that a running total is present.
       '     If the ActiveCell is empty, multiplying by 1 will
       '     return a 0.
             .AddComment
             .Comment.Text Text:="RT= " & (ActiveCell * 1)
          End With
       End Sub
    						

    Excel versions 5.0 and 7.0

    1. On the Insert menu, point to Macro, and then click Module.

      This will insert a new module sheet into your workbook.
    2. Type the following macros into this module sheet:
            ' The Auto_Open name forces this macro to run every time
            ' the workbook containing this macro is opened.
            Sub Auto_Open()
            '  Every time a cell's value is changed,
            '  the RunningTotal macro runs.
               Application.OnEntry = "RunningTotal"
            End Sub
      
            ' This macro sets up a cell to be a running total cell.
            Sub SetNote()
               With ActiveCell
            '     Set note to indicate that a running total is present.
            '     If the ActiveCell is empty, multiplying by 1 will
            '     return a 0.
                  .NoteText Text:="RT_" + (ActiveCell * 1)
               End With
            End Sub
      
            ' This macro runs each time the value of a cell changes.
            ' It adds the current value of the cell to the value of the
            ' cell note. Then it stores the new total in the cell note.
            Sub RunningTotal()
               With Application.Caller
            '     Checks to see if the cell is a running total by
            '     checking to see if the first 3 characters of the cell
            '     note are "RT_".
                  If .NoteText(length:=3) = "RT_" Then
            '        Change the cell's value to the new value in the cell
            '        plus the old total stored in the cell note.
                     .Value = .Value + .NoteText(start:=4)
            '        Store the new total in the cell note.
                     .NoteText "RT_" + .Value
                  End If
               End With
            End Sub
      								

    Excel 4.0 Macro Code Example

    After you enter the macros, define Auto_Open, SetNote, and RunningTotal as command macros that refer to A1, A5, and A9 respectively.
    A1: Auto_Open
    A2: =ON.ENTRY(,"RunningTotal")
    A3: =RETURN()
    A4:
    A5: SetNote
    A6: =NOTE("RT_"&ACTIVE.CELL()*1)
    A7: =RETURN()
    A8:
    A9: RunningTotal
    A10: =IF(GET.NOTE(,,3)="RT_")
    A11: = FORMULA(CALLER()+GET.NOTE(,4),CALLER())
    A12: = NOTE("RT_"&CALLER())
    A13: =END.IF()
    A14: =RETURN()
    Explanation of macro:

    • Cell A1 defines this cell as Auto_Open which causes this macro to run every time the macro sheet is opened.
    • Cell A2 runs the RunningTotal macro every time a cell's value is changed.
    • Cell A3 ends the Auto_Open macro.
    • Cell A5 contains the name of the macro that sets up a cell to be a running total cell.
    • Cell A6 sets the active cell's note to be "RT_" & the value of the active cell.
    • Cell A7 ends the SetNote macro.
    • Cell A9 contains the macro that runs each time the value of a cell changes. It adds the current value of the cell to the value of the cell note. Then it stores the new total in the cell note.
    • Cell A10 checks to see if the cell is a running total by checking to see if the first 3 characters of the cell note are "RT_".
    • Cell A11 changes the cell's value to the new value in the cell and adds the old total stored in the cell note.
    • Cell A12 stores the new total in the cell note.
    • Cell A13 ends the IF() statement.
    • Cell A14 ends the RunningTotal macro.
  2. Save and close your file, and then re-open it.

    The Auto_Open macro that you typed is run when you open your file.
  3. Select the cell that you want to contain the running total.
  4. Follow the appropriate procedure below to run the SetNote (SetComment macro for Microsoft Excel 97) macro.

    Microsoft Excel 97

    1. On the Tools menu, point to Macro, and then click Macros.
    2. In the Macro dialog box, click SetComment and then click Run.

    Microsoft Excel version 5.0 or 7.0

    1. On the Tools menu, click Macro.
    2. From the Macro Name/Reference list, select the macro SetNote, and then click Run.

    Microsoft Excel version 4.0

    1. On the Macro menu, click Run.
    2. Select the SetNote macro, and then click OK.

To Remove a Running Total

To remove a running total, follow the appropriate procedure below for your version of Microsoft Excel.

Excel 97 and Excel 98

  1. Select the cell that contains the running total that you want removed.
  2. Right-click the cell and click "Delete Comment" on the shortcut menu.

Excel versions 5.0 and 7.0

  1. Select the cell on the worksheet that contains the running total.
  2. On the Insert menu, click Note, and then click Delete.

Excel version 4.0

  1. Select the cell on the worksheet that contains the running total.
  2. On the Formula menu, click Note, and then click Delete.

Properties

Article ID: 123578 - Last Review: October 26, 2013 - Revision: 3.0
Applies to
  • Microsoft Excel 97 Standard Edition
  • Microsoft Excel 95 Standard Edition
  • Microsoft Excel 5.0 Standard Edition
  • Microsoft Excel 98 for Macintosh
Keywords: 
kbnosurvey kbarchive kbdtacode kbhowto kbprogramming KB123578

Give Feedback

 

Contact us for more help

Contact us for more help
Connect with Answer Desk for expert help.
Get more support from smallbusiness.support.microsoft.com