VBA Code to copy charts from Excel into PowerPoint

MHamid

Active Member
Joined
Jan 31, 2013
Messages
472
Office Version
  1. 365
Platform
  1. Windows
  2. MacOS
hello

I need some help with a vba code that will copy various charts from 1 excel worksheet into 1 powerpoint slide. I know this is possible, but for some reason I cannot make heads or tails with various codes I've found online.

This is my situation. I have an excel workbook with 16 spreadsheets. However, I only need the vba code to look at 6 of these spreadsheets only. Each spreadsheet has 9 charts that will need to be copied from excel and pasted into 1 slide. So 6 excel worksheets with 9 charts in each copied into 6 pre-existing powerpoint slides ... 9 charts into each slide. For example, there is 1 worksheet labeled "Global" in Excel. The 9 charts located into this worksheet will need to be copied and pasted as a picture into the powerpoint slide labeled "Global".

If anyone sees any other errors in my code, please let me know as well.


Below is my full code:
Code:
Option Explicit
'//-----------------------------------------------------------------------------------//
'  [/b] PptCreator [/b]
'
'  - Purpose: Create EMR Powerpoint
'
'  [/u] Process Steps [/u]
'   -
'   -
'   -
'   -
'   -
'//-----------------------------------------------------------------------------------//
'Declaring Constants
Const sTemplate As String = "[URL="file://naeast.ad.jpmorganchase.com/amercorp$/CORPRE/NARESHARE04/CORP_SEC/METRICS/Reporting/Quality/EMRs/1-Template/Global"]\\Naeast.ad.jpmorganchase.com\amercorp$\CORPRE\NARESHARE04\CORP_SEC\METRICS\Reporting\Quality\EMRs\1-Template\Global[/URL] EMR - Template.pptx"
Const sFinalP As String = "[URL="file://naeast.ad.jpmorganchase.com/amercorp$/CORPRE/NARESHARE04/CORP_SEC/METRICS/Reporting/Quality/EMRs/"]\\Naeast.ad.jpmorganchase.com\amercorp$\CORPRE\NARESHARE04\CORP_SEC\METRICS\Reporting\Quality\EMRs\[/URL]"
'Declaring Helper Variables
Dim aExcel As Excel.Application
Dim wb As Workbook, ws As Worksheet, wsfn As Excel.WorksheetFunction
Dim sDate As String
'Decalring Powerpoint Helpers
Dim aPPT As PowerPoint.Application
Dim pptPres As PowerPoint.Presentation
Dim pptSlide As PowerPoint.Slide, pptSlides As PowerPoint.Slides
Dim pptShape As PowerPoint.Shape
'Dictionary Helper
Dim key As Variant
Private Function GetFinal(s As String) As String
'Declare Helpers
Dim fso As Scripting.FileSystemObject
Dim fsoFile As Scripting.File
Dim fsoFolder As Scripting.Folder
Dim dtmLast As Date
Dim sLast As String
Set fso = New Scripting.FileSystemObject
Set fsoFolder = fso.GetFolder(s)
'Get Most Recent Publication
For Each fsoFile In fsoFolder.Files
    Select Case True
        Case (fsoFile.DateLastModified > dtmLast) And (fsoFile.Name Like "*Global DDO EMR*.xlsx")
            sLast = fsoFile.Path
            dtmLast = fsoFile.DateLastModified
    End Select
Next fsoFile
'/Set Function
GetFinal = sLast
End Function
Sub PptCreator()
'/Setting Variables
Set aExcel = Excel.Application
Set wsfn = Excel.WorksheetFunction
'/PowerPoint
On Error Resume Next
Set aPPT = PowerPoint.Application
If aPPT Is Nothing Then Set aPPT = New PowerPoint.Application
    aPPT.Visible = msoTrue
    aPPT.Activate
On Error GoTo 0
OptiMode
CreatePPT
SavePPT
RegMode
End Sub
Private Sub CreatePPT()
'Helper Variables
Dim nCounter As Integer
Dim chtob As ChartObject
Dim i As Long, total_slide
i = 1

'/Set Variables
Set wb = Workbooks.Open(Filename:=GetFinal(sFinalP), ReadOnly:=False)
'/Powerpoint Operations
Set pptPres = aPPT.Presentations.Open(sTemplate)
'shts = ("Macro Sheet,Summary % Change,Summary Net Change,Region Reference,CIB,GIM,CB,WMIS,Raw Data,Re  ference")
total_slide = pptPres.Slides.Count
'/Create Powerpoint
For Each ws In wb.Sheets
    ws.Select
    
        For Each chtob In ActiveSheet.ChartObjects
        
                    chtob.Copy
                Set pptSlide = pptPres.Slides(i)
                pptSlide.Shapes.PasteSpecial ppPasteShape
                i = i + 1
            If i > total_slide Then Exit Sub
        Next
        
        
Next
'/Create Powerpoint
'For Each ws In wb.Sheets
'    With ws
        'Select Case True
        '    Case (.Name <> "Macro Sheet") And (.Name <> "Summary % Change") And (.Name <> "Summary Net Change") And (.Name <> "Region Reference") And (.Name <> "CIB") And (.Name <> "GIM") And (.Name <> "CB") And (.Name <> "WMIS") And (.Name <> "Raw Data") And (.Name <> "Reference")
        'If InStr(1, shts & ",", ws.CodeName & ",", vbTextCompare) = 0 Then
                            
'        If ws.Name <> "Macro Sheet" And ws.Name <> "Summary % Change" And ws.Name <> "Summary Net Change" And ws.Name <> "Region Reference" And ws.Name <> "CIB" And ws.Name <> "GIM" And ws.Name <> "CB" And ws.Name <> "WMIS" And ws.Name <> "Raw Data" And ws.Name <> "Reference" Then
                         
                    'Do
                        'nCounter = nCounter + 1
                    
                        'Set Range
                        
                        'Copy Chart
 '                       For Each chtob In ActiveSheet.ChartObjects
 '                           chtob.Chart.ChartArea.Copy
                        
                         'Set Powerpoint Slide
 '                       Set pptSlide = pptPres.Slides(SlideDic(.Name, nCounter))
                        
                        'Paste Chart
  '                      pptSlide.Shapes.Paste
                                                
                        'Clear Clipboard
  '                      aExcel.CutCopyMode = False
                    
        'End If
        'End Select
  '  End With
    
 '   nCounter = 0
'Next ws
End Sub
Private Sub SavePPT()
'Helpers
Dim dtmDate As Date, dtmLastWeek
'/Save New Presentation
'Select Case Weekday(Date, vbSunday)
'    Case Is <> 4
'        dtmDate = Date - (Weekday(Date, vbSunday) - 4)
'        dtmLastWeek = dtmDate
'End Select
With pptPres
    .SaveAs sFinalP & "Global EMR - " & Format(dte, "mmmm yyyy") & ".pptx", ppSaveAsPresentation
    .Close
End With
aPPT.Quit
aExcel.DisplayAlerts = False
With wb
    .Close SaveChanges:=False
End With
aExcel.DisplayAlerts = True
End Sub
Private Function SlideDic(sName As String, num As Integer) As Integer
'/Case Switcher
Select Case sName
    Case Is = "Global"
'        Select Case num
'            Case 1
                SlideDic = 0
        End Select
    Case Is = "APAC"
        SlideDic = 1
    Case Is = "North America"
        SlideDic = 2
    Case Is = "Latin America"
        SlideDic = 3
    Case Is = "Bournemouth"
        SlideDic = 4
    Case Is = "Geneva"
        SlideDic = 5
End Select
End Function
Private Function SizePosDic(sName As String, num As Integer) As Variant
'Helpers
Const n As Integer = 72
'/Case Switcher
Select Case sName
    Case Is = "Global"
        Select Case num
            Case 1
                SizePosDic = Array(2 * n, 3.2 * n, 0.85 * n, 2 * n)
            Case 2
                SizePosDic = Array(2 * n, 3.2 * n, 0.85 * n, 3.93 * n)
            Case 3
                SizePosDic = Array(2 * n, 3.2 * n, 0.85 * n, 6 * n)
            Case 4
                SizePosDic = Array(2 * n, 3.2 * n, 4.1 * n, 2 * n)
            Case 5
                SizePosDic = Array(2 * n, 3.2 * n, 4.1 * n, 3.93 * n)
            Case 6
                SizePosDic = Array(2 * n, 3.2 * n, 4.1 * n, 6 * n)
            Case 7
                SizePosDic = Array(2 * n, 3.2 * n, 7.35 * n, 2 * n)
            Case 8
                SizePosDic = Array(2 * n, 3.2 * n, 7.35 * n, 3.93 * n)
            Case 9
                SizePosDic = Array(2 * n, 3.2 * n, 7.35 * n, 6 * n)
        End Select
    Case Is = "APAC"
        Select Case num
            Case 1
                SizePosDic = Array(2 * n, 3.2 * n, 0.85 * n, 2 * n)
            Case 2
                SizePosDic = Array(2 * n, 3.2 * n, 0.85 * n, 3.93 * n)
            Case 3
                SizePosDic = Array(2 * n, 3.2 * n, 0.85 * n, 6 * n)
            Case 4
                SizePosDic = Array(2 * n, 3.2 * n, 4.1 * n, 2 * n)
            Case 5
                SizePosDic = Array(2 * n, 3.2 * n, 4.1 * n, 3.93 * n)
            Case 6
                SizePosDic = Array(2 * n, 3.2 * n, 4.1 * n, 6 * n)
            Case 7
                SizePosDic = Array(2 * n, 3.2 * n, 7.35 * n, 2 * n)
            Case 8
                SizePosDic = Array(2 * n, 3.2 * n, 7.35 * n, 3.93 * n)
            Case 9
                SizePosDic = Array(2 * n, 3.2 * n, 7.35 * n, 6 * n)
        End Select
    Case Is = "North America"
        Select Case num
            Case 1
                SizePosDic = Array(2 * n, 3.2 * n, 0.85 * n, 2 * n)
            Case 2
                SizePosDic = Array(2 * n, 3.2 * n, 0.85 * n, 3.93 * n)
            Case 3
                SizePosDic = Array(2 * n, 3.2 * n, 0.85 * n, 6 * n)
            Case 4
                SizePosDic = Array(2 * n, 3.2 * n, 4.1 * n, 2 * n)
            Case 5
                SizePosDic = Array(2 * n, 3.2 * n, 4.1 * n, 3.93 * n)
            Case 6
                SizePosDic = Array(2 * n, 3.2 * n, 4.1 * n, 6 * n)
            Case 7
                SizePosDic = Array(2 * n, 3.2 * n, 7.35 * n, 2 * n)
            Case 8
                SizePosDic = Array(2 * n, 3.2 * n, 7.35 * n, 3.93 * n)
            Case 9
                SizePosDic = Array(2 * n, 3.2 * n, 7.35 * n, 6 * n)
        End Select
    Case Is = "Latin America"
        Select Case num
            Case 1
                SizePosDic = Array(2 * n, 3.2 * n, 0.85 * n, 2 * n)
            Case 2
                SizePosDic = Array(2 * n, 3.2 * n, 0.85 * n, 3.93 * n)
            Case 3
                SizePosDic = Array(2 * n, 3.2 * n, 0.85 * n, 6 * n)
            Case 4
                SizePosDic = Array(2 * n, 3.2 * n, 4.1 * n, 2 * n)
            Case 5
                SizePosDic = Array(2 * n, 3.2 * n, 4.1 * n, 3.93 * n)
            Case 6
                SizePosDic = Array(2 * n, 3.2 * n, 4.1 * n, 6 * n)
            Case 7
                SizePosDic = Array(2 * n, 3.2 * n, 7.35 * n, 2 * n)
            Case 8
                SizePosDic = Array(2 * n, 3.2 * n, 7.35 * n, 3.93 * n)
            Case 9
                SizePosDic = Array(2 * n, 3.2 * n, 7.35 * n, 6 * n)
        End Select
    Case Is = "Bournemouth"
        Select Case num
            Case 1
                SizePosDic = Array(2 * n, 3.2 * n, 0.85 * n, 2 * n)
            Case 2
                SizePosDic = Array(2 * n, 3.2 * n, 0.85 * n, 3.93 * n)
            Case 3
                SizePosDic = Array(2 * n, 3.2 * n, 0.85 * n, 6 * n)
            Case 4
                SizePosDic = Array(2 * n, 3.2 * n, 4.1 * n, 2 * n)
            Case 5
                SizePosDic = Array(2 * n, 3.2 * n, 4.1 * n, 3.93 * n)
            Case 6
                SizePosDic = Array(2 * n, 3.2 * n, 4.1 * n, 6 * n)
            Case 7
                SizePosDic = Array(2 * n, 3.2 * n, 7.35 * n, 2 * n)
            Case 8
                SizePosDic = Array(2 * n, 3.2 * n, 7.35 * n, 3.93 * n)
            Case 9
                SizePosDic = Array(2 * n, 3.2 * n, 7.35 * n, 6 * n)
        End Select
    Case Is = "Geneva"
        Select Case num
            Case 1
                SizePosDic = Array(2 * n, 3.2 * n, 0.85 * n, 2 * n)
            Case 2
                SizePosDic = Array(2 * n, 3.2 * n, 0.85 * n, 3.93 * n)
            Case 3
                SizePosDic = Array(2 * n, 3.2 * n, 0.85 * n, 6 * n)
            Case 4
                SizePosDic = Array(2 * n, 3.2 * n, 4.1 * n, 2 * n)
            Case 5
                SizePosDic = Array(2 * n, 3.2 * n, 4.1 * n, 3.93 * n)
            Case 6
                SizePosDic = Array(2 * n, 3.2 * n, 4.1 * n, 6 * n)
            Case 7
                SizePosDic = Array(2 * n, 3.2 * n, 7.35 * n, 2 * n)
            Case 8
                SizePosDic = Array(2 * n, 3.2 * n, 7.35 * n, 3.93 * n)
            Case 9
                SizePosDic = Array(2 * n, 3.2 * n, 7.35 * n, 6 * n)
        End Select
End Select
End Function
Private Sub OptiMode()
'Speed Optimization
If aExcel Is Nothing Then Set aExcel = Excel.Application
On Error Resume Next
With aExcel
    .DisplayStatusBar = False
    .EnableEvents = False
    .ScreenUpdating = False
    .Calculation = xlCalculationManual
End With
On Error GoTo 0
End Sub
Private Sub RegMode()
'Regular Operation
If aExcel Is Nothing Then Set aExcel = Excel.Application
On Error Resume Next
With aExcel
    .DisplayStatusBar = True
    .EnableEvents = True
    .ScreenUpdating = True
    .Calculation = xlCalculationAutomatic
End With
On Error GoTo 0
End Sub


This is part of the code that I can't seem to figure out:
Code:
Private Sub CreatePPT()
'Helper Variables
Dim nCounter As Integer
Dim chtob As ChartObject
Dim i As Long, total_slide
i = 1

'/Set Variables
Set wb = Workbooks.Open(Filename:=GetFinal(sFinalP), ReadOnly:=False)
'/Powerpoint Operations
Set pptPres = aPPT.Presentations.Open(sTemplate)
'shts = ("Macro Sheet,Summary % Change,Summary Net Change,Region Reference,CIB,GIM,CB,WMIS,Raw Data,Re  ference")
total_slide = pptPres.Slides.Count
'/Create Powerpoint
For Each ws In wb.Sheets
    ws.Select
    
        For Each chtob In ActiveSheet.ChartObjects
        
                    chtob.Copy
                Set pptSlide = pptPres.Slides(i)
                pptSlide.Shapes.PasteSpecial ppPasteShape
                i = i + 1
            If i > total_slide Then Exit Sub
        Next
        
        
Next
'/Create Powerpoint
'For Each ws In wb.Sheets
'    With ws
        'Select Case True
        '    Case (.Name <> "Macro Sheet") And (.Name <> "Summary % Change") And (.Name <> "Summary Net Change") And (.Name <> "Region Reference") And (.Name <> "CIB") And (.Name <> "GIM") And (.Name <> "CB") And (.Name <> "WMIS") And (.Name <> "Raw Data") And (.Name <> "Reference")
        'If InStr(1, shts & ",", ws.CodeName & ",", vbTextCompare) = 0 Then
                            
'        If ws.Name <> "Macro Sheet" And ws.Name <> "Summary % Change" And ws.Name <> "Summary Net Change" And ws.Name <> "Region Reference" And ws.Name <> "CIB" And ws.Name <> "GIM" And ws.Name <> "CB" And ws.Name <> "WMIS" And ws.Name <> "Raw Data" And ws.Name <> "Reference" Then
                         
                    'Do
                        'nCounter = nCounter + 1
                    
                        'Set Range
                        
                        'Copy Chart
 '                       For Each chtob In ActiveSheet.ChartObjects
 '                           chtob.Chart.ChartArea.Copy
                        
                         'Set Powerpoint Slide
 '                       Set pptSlide = pptPres.Slides(SlideDic(.Name, nCounter))
                        
                        'Paste Chart
  '                      pptSlide.Shapes.Paste
                                                
                        'Clear Clipboard
  '                      aExcel.CutCopyMode = False
                    
        'End If
        'End Select
  '  End With
    
 '   nCounter = 0
'Next ws
End Sub

Thank you
 

Excel Facts

How to change case of text in Excel?
Use =UPPER() for upper case, =LOWER() for lower case, and =PROPER() for proper case. PROPER won't capitalize second c in Mccartney
Two minor errors:

#1
In Private Sub SavePPT()
.SaveAs sFinalP & "Global EMR - " & Format(dte, "mmmm yyyy") & ".pptx", ppSaveAsPresentation 'ERROR change dte to dtmDate
dte is not defined

#2
Line 8 of Private Function SlideDic(sName As String, num As Integer) As Integer
is
End Select
and should be commented out

There are many ways you can refer to a PPT slide, but afaik there is no "labeled" property. , as in ...powerpoint slide labeled "Global". Exactly how is each of your PPT slides labeled (what is the textbox name or placeholder name that contains the label of the slide?)


Here is some code that I think is a bit easier to follow that seems to do about the same thing and demonstrates the copy to PPT:
Code:
Option Explicit

Sub CopyChartsToPPT()

    'If target file is open, copy selection to new slide
    'If target file is not open, create new and save
    
    'Code modified from:
    'http://peltiertech.com/Excel/XL_PPT.html
    'Sub ExcelToExistingPowerPoint()
    
    Dim bGraphOnly As Boolean
    Dim bTable As Boolean
    Dim PPApp As Object ' As PowerPoint.Application
    Dim PPPres As Object ' As PowerPoint.Presentation
    Dim PPSlide As Object ' As PowerPoint.Slide
    Dim sngHeightScale As Single
    Dim sngWidthScale As Single
    Dim sngScale As Single
    Dim sFilePathNameExt As String
    Dim sFilePath As String
    Dim sFileNameExt As String
    Dim bDestPresentationExists As Boolean
    Dim lX As Long
    Dim bDestPresentationOpen As Boolean
    Dim iAnswer As VbMsgBoxResult
    Dim sAction As String
    Dim sAvailID As String
    Dim lSlideIndex As Long
    Dim lChartIndex As Long
    Dim sngInchToPoints
    
    Dim aryCharts(1 To 6) As Variant
        'Each value is an array containing the worksheet name and its 9 charts.
        'Item 1 appears on PPT Slide 1...6 appears on PPT slide 6
        'Replace Chart 1, etc. with the actual name of the charts on each wks that you want to copy
        
    aryCharts(1) = Array("Global", "Chart 1", "Chart 2", "Chart 3", "Chart 4", "Chart 5", "Chart 6", "Chart 7", "Chart 8", "Chart 9")
    aryCharts(2) = Array("APAC", "Chart 1", "Chart 2", "Chart 3", "Chart 4", "Chart 5", "Chart 6", "Chart 7", "Chart 8", "Chart 9")
    aryCharts(3) = Array("North America", "Chart 1", "Chart 2", "Chart 3", "Chart 4", "Chart 5", "Chart 6", "Chart 7", "Chart 8", "Chart 9")
    aryCharts(4) = Array("Latin America", "Chart 1", "Chart 2", "Chart 3", "Chart 4", "Chart 5", "Chart 6", "Chart 7", "Chart 8", "Chart 9")
    aryCharts(5) = Array("Bournemouth", "Chart 1", "Chart 2", "Chart 3", "Chart 4", "Chart 5", "Chart 6", "Chart 7", "Chart 8", "Chart 9")
    aryCharts(6) = Array("Geneva", "Chart 1", "Chart 2", "Chart 3", "Chart 4", "Chart 5", "Chart 6", "Chart 7", "Chart 8", "Chart 9")
        
    'Establish name and path of the PPT file
    sFilePath = ThisWorkbook.path & "\"
    sFileNameExt = "6 Blank Slides.pptx"
    
    'Does PPT file exist on disk in the current directory?
    If Dir(sFilePath & sFileNameExt) <> vbNullString Then bDestPresentationExists = True
    
    ' Reference instance of PowerPoint
    On Error Resume Next
    ' Check whether PowerPoint is running
    Set PPApp = GetObject(, "PowerPoint.Application")
    If PPApp Is Nothing Then
        ' PowerPoint is not running, create new instance
        Set PPApp = CreateObject("PowerPoint.Application")
        ' For automation to work, PowerPoint must be visible
        PPApp.Visible = True
    End If
    On Error GoTo 0
    
    ' Reference existing instance of PowerPoint
    Set PPApp = GetObject(, "Powerpoint.Application")
    
    'Is destination file open in PPT?
    For lX = 1 To PPApp.Presentations.Count
        If PPApp.Presentations(lX).Name = sFileNameExt Then
            PPApp.Presentations(lX).Windows(1).Activate
            bDestPresentationOpen = True
            If bDestPresentationOpen And Not bDestPresentationExists Then
                'open, but not saved to current path, save it there
                PPApp.ActivePresentation.SaveAs sFilePath & sFileNameExt, 11, msoFalse  'ppSaveAsDefault = 11
                bDestPresentationExists = True
                'File may exist in the target directory and be opened from another directory
                '  Since the file will be saved to the target directory shortly, this 'problem' is ignored.
            End If
        End If
    Next
    
    If Not bDestPresentationExists Then
        'DNE, create and save it
        PPApp.Presentations.Add WithWindow:=msoTrue
        PPApp.ActivePresentation.SaveAs sFilePath & sFileNameExt, 11, msoFalse  'ppSaveAsDefault = 11
        bDestPresentationExists = True
        bDestPresentationOpen = True
    End If
    
    If bDestPresentationExists And Not bDestPresentationOpen Then
        'Open the file
        PPApp.Presentations.Open sFilePath & sFileNameExt
    End If
    
    ' Reference active presentation
    Set PPPres = PPApp.ActivePresentation
    PPApp.ActiveWindow.ViewType = 1 ' 1 = ppViewSlide

    For lSlideIndex = 1 To 6
        Set PPSlide = PPPres.Slides(lSlideIndex)
        PPApp.ActiveWindow.View.GotoSlide index:=lSlideIndex
        With Worksheets(aryCharts(lSlideIndex)(0))
            .Select
            For lChartIndex = 1 To 9
                'Copy Image
                .ChartObjects(aryCharts(lSlideIndex)(lChartIndex)).CopyPicture Appearance:=xlScreen, Format:=xlPicture
    
                ' Paste image
                PPSlide.Shapes.Paste.Select
                
                'Resize &  Align pasted image
                With PPApp.ActiveWindow.Selection.ShapeRange
                    .Height = Application.InchesToPoints(2)
                    .Width = Application.InchesToPoints(2)
                    Select Case lChartIndex
                    Case 1 To 3: .Top = Application.InchesToPoints(2)
                    Case 4 To 6: .Top = Application.InchesToPoints(3.93)
                    Case 7 To 9: .Top = Application.InchesToPoints(6)
                    End Select
                    Select Case lChartIndex
                    Case 1, 4, 7: .Left = Application.InchesToPoints(0.83)
                    Case 2, 5, 8: .Left = Application.InchesToPoints(4.1)
                    Case 3, 6, 9: .Left = Application.InchesToPoints(7.35)
                    End Select
                End With
            Next
        End With
    
    Next
    
    PPApp.ActivePresentation.Save

End_Sub:
    
    ' Clean up
    Set PPSlide = Nothing
    Set PPPres = Nothing
    Set PPApp = Nothing

End Sub
 
Upvote 0
Hi Thanks for this code. Can you please advise if i have to paste the chart in specific slide so how to do that. appreciate your help.
 
Upvote 0
If you want to paste on a specific slide, you just need to specify the slide index.

This is assuming that you are adding a slide that doesn't already exist in the PowerPoint Presentation.
Code:
Set PPTSlide = PPTPres.Slides.Add(SLIDEINDEX, ppLayoutBlank)
                 PPTSlide.Shapes.Paste

If you want to paste it to an EXISTING SLIDE then change it to the following:

Code:
Set PPTSlide = PPTPres.Slides(SLIDEINDEX)
                 PPTSlide.Shapes.Paste

I actually have a YouTube video where I explain how to copy different items to a PowerPoint presentation. I'll leave the link in case you want to watch it.

Link To Video:
https://youtu.be/DOaBtYMCCEM


FULL DISCLOSURE THIS IS MY PERSONAL YOUTUBE ACCOUNT
 
Upvote 0

Forum statistics

Threads
1,224,836
Messages
6,181,251
Members
453,027
Latest member
Lost_in_spreadsheets

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