Find

JimmyM1975

New Member
Joined
Feb 11, 2021
Messages
7
Office Version
  1. 2019
Platform
  1. Windows
VBA for Find (and Find/Replace) in series formulae of charts.
I have about 50 workbooks with 20-100 sheets and 50-500 charts in each. Occasionally I need to delete rows with data charted somewhere. This casues the "Excel found a problem with one or more formula references in this worksheet" error and ~Refs inside the series formula of several hundred charts. As find + replace doesnt search in charts we use the VBA from here VBA Charting Techniques but it doesn't do find only (it only does find+replace). I am trying to quickly identify a list to directionally point my to the charts that contain a #ref!. Some have kindly suggested this website: Change Series Formula - Improved Routines - Peltier Tech Blog where for $99 you can by this tool BUT my firm policy wont allow it.

Does anyone have the VBA?
 

Excel Facts

Format cells as currency
Select range and press Ctrl+Shift+4 to format cells as currency. (Shift 4 is the $ sign).
Hi JimmyM1975 and Welcome to this Board. I don't want to interfere with Jon's business, but this seems like it should work.
However, I can't seem to generate/replicate your error to trial the code. So, give it a trial and let me know. HTH. Dave
Code:
Sub test()
Dim sh As Worksheet, ChrtCnt As Integer, SeriesCnt As Integer
For Each sh In ThisWorkbook.Worksheets
sh.Activate
For ChrtCnt = 1 To sh.ChartObjects.Count
For SeriesCnt = 1 To sh.ChartObjects(ChrtCnt).Chart.SeriesCollection.Count
If InStr(sh.ChartObjects(ChrtCnt).Chart.SeriesCollection(SeriesCnt).Formula, "#REF!") Then
MsgBox "Chart: " & sh.ChartObjects(ChrtCnt).Chart.Name & " Series: " & _
                                       SeriesCnt & " has an error!" & vbCrLf _
& sh.ChartObjects(ChrtCnt).Chart.SeriesCollection(SeriesCnt).Formula
Next SeriesCnt
Next ChrtCnt
Next sh
End Sub
To operate run the test sub.
 
Upvote 0
Hi JimmyM1975 and Welcome to this Board. I don't want to interfere with Jon's business, but this seems like it should work.
However, I can't seem to generate/replicate your error to trial the code. So, give it a trial and let me know. HTH. Dave
Code:
Sub test()
Dim sh As Worksheet, ChrtCnt As Integer, SeriesCnt As Integer
For Each sh In ThisWorkbook.Worksheets
sh.Activate
For ChrtCnt = 1 To sh.ChartObjects.Count
For SeriesCnt = 1 To sh.ChartObjects(ChrtCnt).Chart.SeriesCollection.Count
If InStr(sh.ChartObjects(ChrtCnt).Chart.SeriesCollection(SeriesCnt).Formula, "#REF!") Then
MsgBox "Chart: " & sh.ChartObjects(ChrtCnt).Chart.Name & " Series: " & _
                                       SeriesCnt & " has an error!" & vbCrLf _
& sh.ChartObjects(ChrtCnt).Chart.SeriesCollection(SeriesCnt).Formula
Next SeriesCnt
Next ChrtCnt
Next sh
End Sub
To operate run the test sub.
Many thanks for your suggestion - I am not great at VBA so perhaps I am doing something wrong but when I played the macro I receieved a Compile error and the de-bugger stopped on the Next Series Cnt line saying "Next without For". Any suggestions would be very welcome.

1613135466082.png
 
Upvote 0
Whoops! My bad. Missed an "End if" This should compile. Dave
Code:
Sub test()
Dim sh As Worksheet, ChrtCnt As Integer, SeriesCnt As Integer
For Each sh In ThisWorkbook.Worksheets
sh.Activate
For ChrtCnt = 1 To sh.ChartObjects.Count
For SeriesCnt = 1 To sh.ChartObjects(ChrtCnt).Chart.SeriesCollection.Count
If InStr(sh.ChartObjects(ChrtCnt).Chart.SeriesCollection(SeriesCnt).Formula, "#REF!") Then
MsgBox "Chart: " & sh.ChartObjects(ChrtCnt).Chart.Name & " Series: " & _
                                       SeriesCnt & " has an error!" & vbCrLf _
& sh.ChartObjects(ChrtCnt).Chart.SeriesCollection(SeriesCnt).Formula
End If
Next SeriesCnt
Next ChrtCnt
Next sh
End Sub
 
Upvote 0

Forum statistics

Threads
1,213,551
Messages
6,114,272
Members
448,558
Latest member
aivin

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