Construct ShapeRange from dynamic array, or add shape to ShapeRange?

gravanoc

Active Member
Joined
Oct 20, 2015
Messages
351
Office Version
  1. 365
Platform
  1. Windows
  2. Mobile
I'm trying to create a ShapeRange from a number of shapes without knowing how many until runtime.

The method I'm using to create the ShapeRange is [Sheet Name].Shapes.Range(Array([Shape 1].Name, [Shape 2].Name, ... [Shape n].Name))
For ex:
VBA Code:
Dim sR as ShapeRange
Dim shpTable(0 to 1) As Shape

Set shpTable(0) = wks.Shapes("Shape 1")_
Set shpTable(1) = wks. Shapes("Shape 2")

 Set sR = wks.Shapes.Range(Array(shpTable(0).Name, shpTable(1).Name))

I haven't been able to make it work dynamically. One method I tried was constructing a string with the names of the shapes and placing the string in Array().
I don't see a method for ShapeRange that allows me to add shapes to it, either.
 

Excel Facts

Back into an answer in Excel
Use Data, What-If Analysis, Goal Seek to find the correct input cell value to reach a desired result
Your code can be amended so that you assign the shapes' names to your array, instead of the shape itself...

VBA Code:
    Dim sR As ShapeRange
    Dim shpTable(0 To 1) As String
    
    shpTable(0) = wks.Shapes("Shape 1").Name
    shpTable(1) = wks.Shapes("Shape 2").Name
    
    Set sR = wks.Shapes.Range(shpTable)

To make it dynamic, try...

VBA Code:
    Dim ws As Worksheet
    Set ws = ThisWorkbook.Worksheets("Sheet1")
    
    Dim shapesArray() As String
    ReDim shapesArray(1 To ws.Shapes.Count)
    
    Dim shapeIndex As Long
    For shapeIndex = 1 To UBound(shapesArray)
        shapesArray(shapeIndex) = ws.Shapes(shapeIndex).Name
    Next shapeIndex
    
    Dim shpRng As ShapeRange
    Set shpRng = ws.Shapes.Range(shapesArray)

Hope this helps!
 
Upvote 0
Solution

Forum statistics

Threads
1,224,521
Messages
6,179,285
Members
452,902
Latest member
Knuddeluff

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