OzGrid

Limit Scroll Area on an Excel Worksheet

< Back to Search results

 Category: [Excel]  Demo Available 

Limit Scroll Area on an Excel Worksheet

 

Excel VBA: Limit or Restrict Scroll Area on an Excel Worksheet

 

Got any Excel/VBA Questions? Free Excel Help

Limit or Restrict Scroll Area on an Excel Worksheet. 

With the aid of Excel VBA and the Worksheet Selection Event we can restrict the scrollable area on any Excel Worksheet. The code below must be placed in the Private Module of the Worksheet Object. To get their quickly, right click on the Sheet name tab and choose View Code. In here paste the code below. It will restrict the scroll area to only those cells which house data. Note it leaves one extra row and column. This is so more data can be added and the scrollable area is automatically expanded.

Private Sub Worksheet_SelectionChange(ByVal Target As Range)

Dim LastColumn As Integer

Dim LastRow As Long



        If WorksheetFunction.CountA(Cells) > 0 Then

    

        'Search for any entry, by searching backwards by Rows.

        LastRow = Cells.Find(What:="*", After:=[A1], _

                    SearchOrder:=xlByRows, _

                    SearchDirection:=xlPrevious).Row

         If LastRow <> 65536 Then LastRow = LastRow + 1

         

        'Search for any entry, by searching backwards by Columns.

                LastColumn = Cells.Find(What:="*", After:=[A1], _

                    SearchOrder:=xlByColumns, _

                    SearchDirection:=xlPrevious).Column

                 If LastColumn <> 256 Then LastColumn = LastColumn + 1

                 

                 Me.ScrollArea = Range(Cells(1, 1), Cells(LastRow, LastColumn)).Address

    Else

                 Me.ScrollArea = ""

    End If

 End Sub

If you wish to use such code on all Worksheets in the Workbook. Place the code below into the Private Module of the Workbook Object (ThisWorkbook). To get here quickly right click on the Excel icon, top left next to File and choose View Code. In here paste the code below;

Private Sub Workbook_SheetSelectionChange(ByVal Sh As Object, ByVal Target As Range)

Dim LastColumn As Integer

Dim LastRow As Long

Dim LastCell As Range



    If WorksheetFunction.CountA(Sh.Cells) > 0 Then

    

        'Search for any entry, by searching backwards by Rows.

        LastRow = Sh.Cells.Find(What:="*", After:=Sh.Cells(1, 1), _

                    SearchOrder:=xlByRows, _

                    SearchDirection:=xlPrevious).Row

         If LastRow <> 65536 Then LastRow = LastRow + 1

         

        'Search for any entry, by searching backwards by Columns.

                LastColumn = Sh.Cells.Find(What:="*", After:=Sh.Cells(1, 1), _

                    SearchOrder:=xlByColumns, _

                    SearchDirection:=xlPrevious).Column

                 If LastColumn <> 256 Then LastColumn = LastColumn + 1

                 

                 Sh.ScrollArea = Range(Cells(1, 1), Cells(LastRow, LastColumn)).Address

    Else

                 Sh.ScrollArea = ""

    End If



End Sub
 

See also:

Excel: Get Underlying Hyperlink Address
Excel VBA: Create a List of Hyperlinks
Excel VBA: Gather User Data/Input via an InputBox
Inputbox in Excel VBA
Is Workbook Open/Workbook Exists/Worksheet Exists/Auto Filter/How Many Pages Printed
Excel VBA: Create Worksheets for Each Item in an Excel Table of Data
Return Last Chosen Day of Given Month
Find & Return The Last Used Cell On An Excel Worksheet Or Column

 

See also Index to Excel VBA Code and Index to Excel Freebies and Lesson 1 - Excel Fundamentals and Index to how to… providing a range of solutions.

 

Click here to visit our Free 24/7 Excel/VBA Help Forum where there are thousands of posts you can get information from, or you can join the Forum and post your own questions.


Gallery



stars (0 Reviews)