|
|
|
|
|
|
Excel
|
List all formulas in a workbook on a separate worksheet
|
|
Ease of Use
|
Easy
|
Version tested with
|
97, 2000, 2003
|
Submitted by:
|
Glaswegian
|
Description:
|
This code creates a list all formulas in a workbook. A new worksheet is added and the formulas, including the sheet name and cell address, are listed in Columns A, B and C.
|
Discussion:
|
It can be difficult to keep track of all the formulas within a large workbook. This code will create a list of all the formulas, along with the sheet name and cell address. This can be useful if someone needs to review the formulas used or if you just need to find one particular formula or a set of formulas. A new worksheet is created, named by the user via an Input Box, and headings added. The new sheet is then excluded from the loop. UsedRange and SpecialCells are used to reduce the need to search every cell on each sheet. Once a cell with a formula is found, the code removes the equals sign (=) from the formula to allow the details to be placed in the new sheet without a calculation taking place. The sheet name and cell address are then added as well.
|
Code:
|
instructions for use
|
Option Explicit
Sub ListAllFormulas()
Dim sht As Worksheet
Dim shtName
Dim myRng As Range
Dim newRng As Range
Dim c As Range
ReTry:
shtName = Application.InputBox("Choose a name for the new sheet to list all formulas.", "New Sheet Name")
If shtName = False Then Exit Sub
On Error Resume Next
Set sht = Sheets(shtName)
If Not sht Is Nothing Then
MsgBox "This sheet already exists"
Err.Clear
Set sht = Nothing
GoTo ReTry
End If
Worksheets.Add.Move after:=Worksheets(Worksheets.Count)
Application.ScreenUpdating = False
With ActiveSheet
.Range("A1").Value = "Formula"
.Range("B1").Value = "Sheet Name"
.Range("C1").Value = "Cell Address"
.Name = shtName
End With
For Each sht In ActiveWorkbook.Worksheets
If sht.Name <> shtName Then
Set myRng = sht.UsedRange
On Error Resume Next
Set newRng = myRng.SpecialCells(xlCellTypeFormulas)
For Each c In newRng
Sheets(shtName).Range("A65536").End(xlUp).Offset(1, 0).Value = Mid(c.Formula, 2, (Len(c.Formula)))
Sheets(shtName).Range("B65536").End(xlUp).Offset(1, 0).Value = sht.Name
Sheets(shtName).Range("C65536").End(xlUp).Offset(1, 0).Value = Application.WorksheetFunction.Substitute(c.Address, "$", "")
Next c
End If
Next sht
Sheets(shtName).Activate
ActiveSheet.Columns("A:C").AutoFit
Application.ScreenUpdating = True
End Sub
|
How to use:
|
- Press Alt+F11 from Excel to open the VB Editor.
- Click on the Project(Workbook) name in the left pane.
- Click on ?Insert? on the Menu Bar
- Select ?Module? from the list. The new Module will open.
- Paste the code into the right pane of the Module.
- Click on Alt+F11 to return to Excel
|
Test the code:
|
- Can be run in any workbook or from your Personal.xls file.
- Press Alt+F8 and select the macro name from the list or from the menu bar, click
- Tools > Macro > Macros and select the macro name from the list.
- Or create a button and add the code to the button.
|
Sample File:
|
Sample Formulas.zip 15.22KB
|
Approved by mdmackillop
|
This entry has been viewed 371 times.
|
|