positioning a shape on a calendar based on a given date.

ifu06416

Board Regular
Joined
Sep 5, 2011
Messages
56
Office Version
  1. 365
Hello,

I'm trying to build a customized Gantt chart on excel.

I have a template with task start dates (col B) and end dates (col C) followed by the 12 months of the year (cols E-P).

I have the code below to generate the task duration bars.

The difficulty Im having is figuring out how to position the start of the bar relative to the task start month (col B) and the end of the bar relative to the end month (col C).

If anyone has any ideas it would be appreciated.

Regards,

John.
1641377275619.png
VBA Code:
Sub CreateShapes2()

Dim Start_Diamond As Shape
Dim End_Diamond As Shape
Dim conn As Shape
Dim rngPlace As Excel.Range

'set reference to a worksheet
Set w = ActiveSheet

'add Start Diamond
 Set rngPlace = w.Range("E4")
 With rngPlace
 Set Start_Diamond = w.Shapes.AddShape(msoShapeDiamond, 300.5, 35, 8.5, 9.6)


'Add end diamond
Set End_Diamond = w.Shapes.AddShape(4, 600.5, 35, 8.5, 9.6)

'Set the connector link
Set conn = w.Shapes.AddConnector(msoConnectorStraight, 15, 150, 15, 150)

conn.ConnectorFormat.BeginConnect Start_Diamond, 1
conn.ConnectorFormat.EndConnect End_Diamond, 1
conn.RerouteConnections


End With
End Sub
 

Excel Facts

Add Bullets to Range
Select range. Press Ctrl+1. On Number tab, choose Custom. Type Alt+7 then space then @ sign (using 7 on numeric keypad)
I have amended your macro as follows . . .

VBA Code:
Sub CreateShapes2()

    Dim ws As Worksheet
    Dim Start_Diamond As Shape
    Dim End_Diamond As Shape
    Dim conn As Shape
    Dim Start_Range As Range
    Dim End_Range As Range
    Dim Start_Pos As Single
    Dim End_Pos As Single
    
    On Error GoTo errorHandler
    
    'set reference to a worksheet
    Set ws = ActiveSheet
    
    'find start and end ranges
    With Application
        Set Start_Range = .Index(ws.Range("E4:P4"), .Match(Format(ws.Range("B4").Value, "mmm"), ws.Range("E3:P3"), 0))
        Set End_Range = .Index(ws.Range("E4:P4"), .Match(Format(ws.Range("C4").Value, "mmm"), ws.Range("E3:P3"), 0))
    End With
    
    'find start position
    With Start_Range
        Start_Pos = .Left + (.Width / 2) - (8.5 / 2)
    End With
    
    'find end position
    With End_Range
        End_Pos = .Left + (.Width / 2) - (8.5 / 2)
    End With
    
    'add Start Diamond
     Set Start_Diamond = ws.Shapes.AddShape(msoShapeDiamond, Start_Pos, Start_Range.Top + 2, 8.5, 9.6)
    
     'add End Diamond
     Set End_Diamond = ws.Shapes.AddShape(msoShapeDiamond, End_Pos, End_Range.Top + 2, 8.5, 9.6)
    
    'Set the connector link
    Set conn = ws.Shapes.AddConnector(msoConnectorStraight, 15, 150, 15, 150)
    
    conn.ConnectorFormat.BeginConnect Start_Diamond, 1
    conn.ConnectorFormat.EndConnect End_Diamond, 1
    conn.RerouteConnections
    
exitHandler:
    Exit Sub
    
errorHandler:
    MsgBox "Error " & Err.Number & ":  " & Err.Description, vbCritical, "Error"
    Resume exitHandler
    
End Sub

Note that I have also added an error handler.

Hope this helps!
 
Upvote 0
I have amended your macro as follows . . .

VBA Code:
Sub CreateShapes2()

    Dim ws As Worksheet
    Dim Start_Diamond As Shape
    Dim End_Diamond As Shape
    Dim conn As Shape
    Dim Start_Range As Range
    Dim End_Range As Range
    Dim Start_Pos As Single
    Dim End_Pos As Single
   
    On Error GoTo errorHandler
   
    'set reference to a worksheet
    Set ws = ActiveSheet
   
    'find start and end ranges
    With Application
        Set Start_Range = .Index(ws.Range("E4:P4"), .Match(Format(ws.Range("B4").Value, "mmm"), ws.Range("E3:P3"), 0))
        Set End_Range = .Index(ws.Range("E4:P4"), .Match(Format(ws.Range("C4").Value, "mmm"), ws.Range("E3:P3"), 0))
    End With
   
    'find start position
    With Start_Range
        Start_Pos = .Left + (.Width / 2) - (8.5 / 2)
    End With
   
    'find end position
    With End_Range
        End_Pos = .Left + (.Width / 2) - (8.5 / 2)
    End With
   
    'add Start Diamond
     Set Start_Diamond = ws.Shapes.AddShape(msoShapeDiamond, Start_Pos, Start_Range.Top + 2, 8.5, 9.6)
   
     'add End Diamond
     Set End_Diamond = ws.Shapes.AddShape(msoShapeDiamond, End_Pos, End_Range.Top + 2, 8.5, 9.6)
   
    'Set the connector link
    Set conn = ws.Shapes.AddConnector(msoConnectorStraight, 15, 150, 15, 150)
   
    conn.ConnectorFormat.BeginConnect Start_Diamond, 1
    conn.ConnectorFormat.EndConnect End_Diamond, 1
    conn.RerouteConnections
   
exitHandler:
    Exit Sub
   
errorHandler:
    MsgBox "Error " & Err.Number & ":  " & Err.Description, vbCritical, "Error"
    Resume exitHandler
   
End Sub

Note that I have also added an error handler.

Hope this helps!
Oh wow, you've actually done it for me ?

That works perfectly, thanks so much.

Regards,

John.
 
Upvote 0
You're very welcome, and thanks for the feedback.

Cheers!
 
Upvote 0

Forum statistics

Threads
1,223,275
Messages
6,171,126
Members
452,381
Latest member
Nova88

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