VBA "ignoring" or exit sub with "Select All"

arkusM

Well-known Member
Joined
Apr 12, 2007
Messages
560
Good day!

I am trying to prevent a out of memory error when all cells as selected.
Basically I am lookinf for a way to test if the user selects all the cells in a sheet. Then if that happen I want to exit the sub.
Basically
IF "Select all" then Exit Sub
But I don;t know what syntax to use for the "select all" part.
I know that cells.select does select all but if I try

Code:
If ActiveSheet.Cells.Select is True then Exit Sub
I gets into some strange loop and Excel locks up.

Any pointers?
 
It's no problem. Fingers crossed that it works - I may have overlooked something so don't hesitate to post back if there's an issue.

Btw - when I'm picking up code from somewhere on the web, I'm always a bit hesitant if it's a long procedure covered by an 'On Error Resume Next' statement.


Advice noted.
I had turned that off at one point to try and find issues. I try not to use on error resume next too often...

Thanks again!
 
Upvote 0

Excel Facts

Create a chart in one keystroke
Select the data and press Alt+F1 to insert a default chart. You can change the default chart to any chart type
Change Tracker VB

For the sake of postarity:

The "final" code looks like this and goes in the 'ThisWorkbook' code:
I added the ability to track over 2 million changes buy moving over columns when the current set is full.
In the "Precursor Exits" section allows for some customization for exits.
I implements this not to track certian sheets.
and at present if the entry data is new then don't bother recording it but, change it and it is recorded.

Note: While testing I had only 65,580 line and the file quickly bloated to 7 Mb!! And the data in the "Tracker" tab is pure data no formulas!! I cannot imagine really big files!!

I would like to make this an XLA someday for my company...
Thanks to Ozgrid.com!! and Colin_L

Code:
Option Explicit
Dim sOldAddress As String
Dim vOldValue As Variant
Dim sOldFormula As String
 
Private Sub Workbook_SheetChange(ByVal Sh As Object, ByVal Target As Range)
    'http://www.mrexcel.com/forum/showthread.php?t=376400&referrerid=76744
    'Thanks to Colin_L and Ozgrid.com
    Dim wSheet As Worksheet
    Dim wActSheet As Worksheet
    Dim iCol As Integer
    Set wActSheet = ActiveSheet
 
    'Precursor Exits
 
    If vOldValue = "" Then Exit Sub
 
    'Continue
 
    On Error Resume Next ' This Error resume next is only to allow the creation of the tracker sheet.
        Set wSheet = Sheets("Tracker")
    '**** Add the tracker Sheet if it does not exist ****
 
        If wSheet Is Nothing Then
            Set wActSheet = ActiveSheet
            Worksheets.Add(After:=Worksheets(Worksheets.Count)).Name = "Tracker"
        End If
    On Error GoTo 0
   '**** End of specific error resume next
 
    On Error GoTo ErrorHandler
    With Application
         .ScreenUpdating = False
         .EnableEvents = False
    End With
 
    With Sheets("Tracker")
    '******** This bit of code moves the tracker over a column when the first columns are full**'
        If .Cells(1, 1) = "" Then                                                               '
            iCol = 1                                                                            '
        Else                                                                                    '
            iCol = .Cells(1, 256).End(xlToLeft).Column - 7                                      '
            If Not .Cells(65536, iCol) = "" Then                                                '
                iCol = .Cells(1, 256).End(xlToLeft).Column + 1                                  '
            End If                                                                              '
        End If                                                                                  '
    '********* END *****************************************************************************'
        .Unprotect Password:="Secret"
 
    '******** Sets the Column Headers **********************************************************
        If LenB(.Cells(1, iCol).Value) = 0 Then
            .Range(.Cells(1, iCol), .Cells(1, iCol + 7)) = Array("Cell Changed", "Old Value", _
                    "New Value", "Old Formula", "New Formula", "Time of Change", "Date of Change", "User")
            .Cells.Columns.AutoFit
 
        End If
 
           With .Cells(.Rows.Count, iCol).End(xlUp).Offset(1)
 
               .Value = sOldAddress
               .Offset(0, 1).Value = vOldValue
               .Offset(0, 3).Value = sOldFormula
 
               If Target.Count = 1 Then
                   .Offset(0, 2).Value = Target.Value
                   If Target.HasFormula Then .Offset(0, 4).Value = "'" & Target.Formula
               End If
 
                .Offset(0, 5) = Time
                .Offset(0, 6) = Date
                .Offset(0, 7) = Application.UserName
                .Offset(0, 7).Borders(xlEdgeRight).LineStyle = xlContinuous
           End With
 
          .Protect Password:="Secret"
 
        End With
ErrorExit:
    With Application
         .ScreenUpdating = True
         .EnableEvents = True
    End With
 
    wActSheet.Activate
    Exit Sub
 
ErrorHandler:
    'any error handling you want
    Debug.Print "We have an error"
    Resume ErrorExit
 
End Sub
 
Private Sub Workbook_SheetSelectionChange(ByVal Sh As Object, ByVal Target As Range)
 
    With Target
        sOldAddress = .Address(external:=True)
 
        If .Count > 1 Then
 
            vOldValue = "Multiple Cell Select"
            sOldFormula = vbNullString
 
        Else
 
            vOldValue = .Value
            If .HasFormula Then
                sOldFormula = "'" & Target.Formula
            Else
                sOldFormula = vbNullString
            End If
        End If
    End With
End Sub
Sub react()
    With Application
         .ScreenUpdating = True
         .EnableEvents = True
    End With
End Sub
 
Upvote 0
Hi Guys,

Thanks a Lot for this Code
I tried it out and works good if the workbook is from my login only. I have this workbook on a Public Drive --but this code doesn't seem to record any other users changes who access it from other computers. I tried this out for two days with multiple users . I need to know what seems to be the problem

can someone help??
 
Upvote 0
Hi Guys,

Thanks a Lot for this Code
I tried it out and works good if the workbook is from my login only. I have this workbook on a Public Drive --but this code doesn't seem to record any other users changes who access it from other computers. I tried this out for two days with multiple users . I need to know what seems to be the problem

can someone help??

Not sure why you are having the issue, I have not had the same problem with the file I built this for on a public drive accessed by different users.
Are all the users allowing Macros? Ie Security issues. If it i critical that the cahanges be tracked then i might worth look up how to lock down the spreadsheet so it is unusable until macros are allowed...
 
Upvote 0

Forum statistics

Threads
1,216,480
Messages
6,130,905
Members
449,606
Latest member
jaybar0812

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top