Run-time error '-2147024809 (80070057') The index into the specified collection is out of bounds

bmunkel

New Member
Joined
Oct 27, 2015
Messages
7
Please bear with me...learning as I go
I have a macro that I have run successfully in Excel for the past two years but continue to get the following message on my latest project: "Run-time error '-2147024809 (80070057') The index into the specified collection is out of bounds". I am referencing more shapes than I have done in previous iterations (204 shapes in file) but not sure if that has anything to do with the issue. The macro follows:

Sub MapMacro()

<code style="margin: 0px; padding: 0px; border: 0px; font-style: inherit; font-variant: inherit; font-weight: inherit; font-stretch: inherit; line-height: inherit; font-family: Consolas, Menlo, Monaco, "Lucida Console", "Liberation Mono", "DejaVu Sans Mono", "Bitstream Vera Sans Mono", "Courier New", monospace, sans-serif; vertical-align: baseline; box-sizing: inherit; white-space: inherit;">For i =5To207
Range
("actReg").Value = Range("A"& i).Value

If ActiveSheet.Name ="Variables"Then
Worksheets
("Map").Activate
EndIf

ActiveSheet
.Shapes(Range("actReg").Value).Select
Selection
.ShapeRange.Fill.ForeColor.RGB = Range(Range("actRegCode").Value).Interior.Color

If ActiveSheet.Name ="Map"Then
Worksheets
("Variables").Activate
EndIf

Next i

Range
("A1").Select
</code>End Sub

Any assistance is greatly appreciated!!!
 

Excel Facts

Pivot Table Drill Down
Double-click any number in a pivot table to create a new report showing all detail rows that make up that number
I get the error when the actReg range has 211 in it because there are only 205 shapes on the sheet, so you can't select shape 211.

Also, you could eliminate all that flickering like this:

Code:
Sub MapMacro()
    Dim mapSheet As Worksheet
    Dim varSheet As Worksheet
    
    Set mapSheet = Worksheets("Map")
    Set varSheet = Worksheets("Variables")
    
    For i = 5 To 207
        varSheet.Range("actReg").Value = varSheet.Range("A" & i).Value
        mapSheet.Shapes(Range("actReg").Value).Fill.ForeColor.RGB = varSheet.Range("actRegCode").Interior.Color
    
    Next i

End Sub
 
Last edited:
Upvote 0
Many thanks (sometimes the solution is simple)!!! Worked for the first few and assume it will work for the rest...will just go through and rename shapes to include verbiage as well as numbers and should run perfectly....much appreciated!

I get the error when the actReg range has 211 in it because there are only 205 shapes on the sheet, so you can't select shape 211.

Also, you could eliminate all that flickering like this:

Code:
Sub MapMacro()
    Dim mapSheet As Worksheet
    Dim varSheet As Worksheet
    
    Set mapSheet = Worksheets("Map")
    Set varSheet = Worksheets("Variables")
    
    For i = 5 To 207
        varSheet.Range("actReg").Value = varSheet.Range("A" & i).Value
        mapSheet.Shapes(Range("actReg").Value).Fill.ForeColor.RGB = varSheet.Range("actRegCode").Interior.Color
    
    Next i

End Sub
 
Upvote 0

Forum statistics

Threads
1,214,875
Messages
6,122,040
Members
449,063
Latest member
ak94

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