PDA

View Full Version : How to Insert new PowerPivotChart into Excel 2013 via VBA?



Ted Murphy
2016-04-14, 02:13 PM
It is not possible to insert a PowerPivotChart into a worksheet in Excel 2013 without opening the Data Model window, which can be intimidating for an end user consumer.

The only alternative is to create a VBA macro that will perform the task.

Matt Allington, with assistance from Dominik Petri, published the script below to create a insert a PowerPivotTable. It work a treat.

I have tried to create a variation that would allow a PowerPivotChart to be inserted. However, my VBA skills don't stretch that far and I came unstuck.

Does anyone have the time (and capability) to modify the Macro so that it will work for a Chart?

Any help would be much appreciated. The macro will be very useful to anyone using PowerPivot in Excel 2013.

Macro for Pivot Table as published by Matt Allington (with input from Dominik Petri)



Sub InsertPowerPivotTable()Dim PowerPivotCache As Excel.PivotCache
Dim NewPowerPivotTable As Excel.PivotTable


‘ Create new cache
Set PowerPivotCache = ActiveWorkbook.PivotCaches.Create( _
SourceType:=xlExternal, _
SourceData:=ActiveWorkbook.Connections(“ThisWorkbookDataModel”), _
Version:=xlPivotTableVersion15)


‘ Create PivotTable
Set NewPowerPivotTable = PowerPivotCache.CreatePivotTable( _
TableDestination:=ActiveCell, _
DefaultVersion:=xlPivotTableVersion15)


‘ Settings for new PowerPivotTable
With NewPowerPivotTable
.RowAxisLayout xlTabularRow
.HasAutoFormat = False
End With


‘ Cleanup
Set NewPowerPivotTable = Nothing
Set PowerPivotCache = Nothing


End Sub

Ken Puls
2016-04-15, 06:04 PM
Hey Ted,

I'm not in love with this macro, as it seems to require creating a chart sheet, then turning it into a proper chart. At the end of the day, though, it does work:


Sub CreatePivotChart()

Dim objPivot As PivotTable
Dim objChart As Chart
Dim sPivotName As String
Dim sPivotSheet As String

'Set the name of the sheet that holds the pivot table and the name of the pivot chart
sPivotSheet = "Dashboard"
sPivotName = "PivotTable2"

'Bind to the desired pivot table.
On Error Resume Next
Set objPivot = Worksheets(sPivotSheet).PivotTables(sPivotName)
If Err.Number <> 0 Then Exit Sub
On Error GoTo 0

'This creates a new chart sheet (don't worry, we'll change that later.)
Set objChart = Charts.Add

'Configure the PivotChart here.
With objChart
.SetSourceData objPivot.TableRange1
.ChartType = xlLine
.Legend.Delete
End With

'Convert from chart sheet into chart
ActiveChart.Location Where:=xlLocationAsObject, Name:=objPivot.Parent.Name

End Sub