Copy range as jpg without creating/deleting chart?

Joseph Lo

New Member
Joined
Dec 19, 2013
Messages
40
Hi guys,

I have adapted this code to my spreadsheet.

Code:
Private Sub CommandButton1_Click()


    Dim rgExp As Range: Set rgExp = Range("D6:Q27")
    ''' Copy range as picture onto Clipboard
    
    rgExp.CopyPicture Appearance:=xlScreen, Format:=xlBitmap
    ''' Create an empty chart with exact size of range copied
    
    With ActiveSheet.ChartObjects.Add(Left:=rgExp.Left, Top:=rgExp.Top, _
    Width:=rgExp.Width, Height:=rgExp.Height)
    .Name = "Table"
    .Activate
    End With
    
    ''' Paste into chart area, export to file, delete chart.
    Application.EnableEvents = False
    ActiveChart.Paste
    ActiveSheet.ChartObjects("Table").Chart.Export Filename:=Application.ActiveWorkbook.Path & "\T25(1).jpg", Filtername:="jpg"
    ActiveSheet.ChartObjects("Table").Delete
    Application.EnableEvents = True


End Sub

It works fine but only when the worksheet and workbook is not password protected. When the worksheet/workbook is protected, the sub-routine will fail.

So my question is: Is there any way I can export a saved range to a jpg via another method?

Thanks
 
In that case, try this. In a new module:
Code:
 '***************************************************************************'*
 '* AUTHOR & DATE:   STEPHEN BULLEN, Office Automation Ltd
 '*                  15 November 1998
 
 
 '*
 '* DESCRIPTION:     Creates a standard Picture object from whatever is on the clipboard.
 '*                  This object can then be assigned to (for example) and Image control
 '*                  on a userform.  The PastePicture function takes an optional argument of
 '*                  the picture type - xlBitmap or xlPicture.
 '*
 '*                  The code requires a reference to the "OLE Automation" type library
 '*
 '*                  The code in this module has been derived from a number of sources
 '*                  discovered on MSDN.
 '*
 '*                  To use it:
 '*                      Set Image1.Picture = PastePicture(xlPicture)
 '*                  to paste a picture of whatever is on the clipboard into a standard image control.
 '*
 '* PROCEDURES:
 '*   PastePicture   The entry point for the routine
 '*   CreatePicture  Private function to convert a bitmap or metafile handle to an OLE reference
 '*   fnOLEError     Get the error text for an OLE error code
 '***************************************************************************
 'Option Private Module
Option Explicit
Option Compare Text
 
 'The API format types we're interested in
Const CF_BITMAP = 2
Const CF_PALETTE = 9
Const CF_ENHMETAFILE = 14
Const IMAGE_BITMAP = 0
Const LR_COPYRETURNORG = &H4

 ''' User-Defined Types for API Calls
 
 
 'Declare a UDT to store a GUID for the IPicture OLE Interface
Private Type GUID
    Data1 As Long
    Data2 As Integer
    Data3 As Integer
    Data4(0 To 7) As Byte
End Type
 
 
 '''Windows API Function Declarations
#If VBA7 Then
     
     
    Private Type uPicDesc
        Size As Long
        Type As Long
        hPic As LongPtr
        hPal As LongPtr
    End Type
         
         
     'Does the clipboard contain a bitmap/metafile?
    Private Declare PtrSafe Function IsClipboardFormatAvailable Lib "user32" (ByVal wFormat As Long) As Long
     
     'Open the clipboard to read
    Private Declare PtrSafe Function OpenClipboard Lib "user32" (ByVal hWnd As LongPtr) As Long
     
     'Get a pointer to the bitmap/metafile
    Private Declare PtrSafe Function GetClipboardData Lib "user32" (ByVal wFormat As Long) As LongPtr
     
     'Close the clipboard
    Private Declare PtrSafe Function CloseClipboard Lib "user32" () As Long
     
     'Convert the handle into an OLE IPicture interface.
    Private Declare PtrSafe Function OleCreatePictureIndirect Lib "oleaut32.dll" (PicDesc As uPicDesc, RefIID As GUID, _
                                                    ByVal fPictureOwnsHandle As LongPtr, IPic As IPicture) As Long
     
     
     'Create our own copy of the metafile, so it doesn't get wiped out by subsequent clipboard updates.
    Declare PtrSafe Function CopyEnhMetaFile Lib "gdi32" Alias "CopyEnhMetaFileA" (ByVal hemfSrc As LongPtr, ByVal lpszFile As String) As LongPtr
     
     
     'Create our own copy of the bitmap, so it doesn't get wiped out by subsequent clipboard updates.
    Declare PtrSafe Function CopyImage Lib "user32" (ByVal Handle As LongPtr, ByVal un1 As Long, _
                                    ByVal n1 As Long, ByVal n2 As Long, ByVal un2 As Long) As LongPtr
     
     
#Else
     
     
     'Declare a UDT to store the bitmap information
    Private Type uPicDesc
        Size As Long
        Type As Long
        hPic As Long
        hPal As Long
    End Type
         
         
     'Does the clipboard contain a bitmap/metafile?
    Private Declare Function IsClipboardFormatAvailable Lib "user32" (ByVal wFormat As Long) As Long
     
     
     'Open the clipboard to read
    Private Declare Function OpenClipboard Lib "user32" (ByVal hWnd As Long) As Long
     
     
     'Get a pointer to the bitmap/metafile
    Private Declare Function GetClipboardData Lib "user32" (ByVal wFormat As Long) As Long
     
     
     'Close the clipboard
    Private Declare Function CloseClipboard Lib "user32" () As Long
     
     
     'Convert the handle into an OLE IPicture interface.
    Private Declare Function OleCreatePictureIndirect Lib "olepro32.dll" (PicDesc As uPicDesc, RefIID As GUID, _
                                                    ByVal fPictureOwnsHandle As Long, IPic As IPicture) As Long
     
     
     'Create our own copy of the metafile, so it doesn't get wiped out by subsequent clipboard updates.
    Declare Function CopyEnhMetaFile Lib "gdi32" Alias "CopyEnhMetaFileA" (ByVal hemfSrc As Long, ByVal lpszFile As String) As Long
     
     
     'Create our own copy of the bitmap, so it doesn't get wiped out by subsequent clipboard updates.
    Declare Function CopyImage Lib "user32" (ByVal Handle As Long, ByVal un1 As Long, _
                        ByVal n1 As Long, ByVal n2 As Long, ByVal un2 As Long) As Long
     

#End If
     
     
     
     
         
 
 ''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''
 ''' Subroutine: PastePicture
 '''
 ''' Purpose:    Get a Picture object showing whatever's on the clipboard.
 '''
 ''' Arguments:  lXlPicType - The type of picture to create.  Can be one of:
 '''                          xlPicture to create a metafile (default)
 '''                          xlBitmap to create a bitmap
 '''
 ''' Date        Developer           Action
 ''' ------------------------------------------------------c--------------------
 ''' 30 Oct 98   Stephen Bullen      Created
 ''' 15 Nov 98   Stephen Bullen      Updated to create our own copies of the clipboard images
 '''
 
Function PastePicture(Optional lXlPicType As Long = xlPicture) As IPicture
     
     
     'Some pointers
#If VBA7 Then
    Dim hPtr As LongPtr
    Dim hPal As LongPtr
    Dim hCopy As LongPtr
#Else
    Dim hPtr As Long
    Dim hPal As Long
    Dim hCopy As Long
#End If
    Dim H As Long
    Dim hPicAvail As Long
    Dim lPicType As Long
     
     'Convert the type of picture requested from the xl constant to the API constant
    lPicType = IIf(lXlPicType = xlBitmap, CF_BITMAP, CF_ENHMETAFILE)
     
     'Check if the clipboard contains the required format
    hPicAvail = IsClipboardFormatAvailable(lPicType)
     
    If hPicAvail <> 0 Then
         'Get access to the clipboard
        H = OpenClipboard(0&)
         
        If H > 0 Then
             'Get a handle to the image data
            hPtr = GetClipboardData(lPicType)
             
             'Create our own copy of the image on the clipboard, in the appropriate format.
            If lPicType = CF_BITMAP Then
                hCopy = CopyImage(hPtr, IMAGE_BITMAP, 0, 0, LR_COPYRETURNORG)
            Else
                hCopy = CopyEnhMetaFile(hPtr, vbNullString)
            End If
             
             'Release the clipboard to other programs
            H = CloseClipboard
             
             'If we got a handle to the image, convert it into a Picture object and return it
            If hPtr <> 0 Then Set PastePicture = CreatePicture(hCopy, 0, lPicType)
        End If
    End If
     
     
End Function

         
         
         
 ''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''
 ''' Subroutine: CreatePicture
 '''
 ''' Purpose:    Converts a image (and palette) handle into a Picture object.
 '''
 '''             Requires a reference to the "OLE Automation" type library
 '''
 ''' Arguments:  None
 '''
 ''' Date        Developer           Action
 ''' --------------------------------------------------------------------------
 ''' 30 Oct 98  Stephen Bullen      Created
 '''
#If VBA7 Then
    Private Function CreatePicture(ByVal hPic As LongPtr, ByVal hPal As LongPtr, ByVal lPicType) As IPicture
#Else
    Private Function CreatePicture(ByVal hPic As Long, ByVal hPal As Long, ByVal lPicType) As IPicture
#End If
     ' IPicture requires a reference to "OLE Automation"
    Dim r As Long, uPicInfo As uPicDesc, IID_IDispatch As GUID, IPic As IPicture
     
     
     'OLE Picture types
    Const PICTYPE_BITMAP = 1
    Const PICTYPE_ENHMETAFILE = 4
     
     
     ' Create the Interface GUID (for the IPicture interface)
    With IID_IDispatch
        .Data1 = &H7BF80980
        .Data2 = &HBF32
        .Data3 = &H101A
        .Data4(0) = &H8B
        .Data4(1) = &HBB
        .Data4(2) = &H0
        .Data4(3) = &HAA
        .Data4(4) = &H0
        .Data4(5) = &H30
        .Data4(6) = &HC
        .Data4(7) = &HAB
    End With
     
     
     ' Fill uPicInfo with necessary parts.
    With uPicInfo
        .Size = Len(uPicInfo) ' Length of structure.
        .Type = IIf(lPicType = CF_BITMAP, PICTYPE_BITMAP, PICTYPE_ENHMETAFILE) ' Type of Picture
        .hPic = hPic ' Handle to image.
        .hPal = IIf(lPicType = CF_BITMAP, hPal, 0) ' Handle to palette (if bitmap).
    End With
     
     ' Create the Picture object.
    r = OleCreatePictureIndirect(uPicInfo, IID_IDispatch, 1, IPic)
     
     
     ' If an error occured, show the description
    If r <> 0 Then Debug.Print "Create Picture: " & fnOLEError(r)
     
     
     ' Return the new Picture object.
    Set CreatePicture = IPic
     
     
End Function
 
 
 
 ''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''
 ''' Subroutine: fnOLEError
 '''
 ''' Purpose:    Gets the message text for standard OLE errors
 '''
 ''' Arguments:  None
 '''
 ''' Date        Developer           Action
 ''' --------------------------------------------------------------------------
 ''' 30 Oct 98   Stephen Bullen      Created
 '''
 
 
Private Function fnOLEError(lErrNum As Long) As String
     
     
     'OLECreatePictureIndirect return values
    Const E_ABORT = &H80004004
    Const E_ACCESSDENIED = &H80070005
    Const E_FAIL = &H80004005
    Const E_HANDLE = &H80070006
    Const E_INVALIDARG = &H80070057
    Const E_NOINTERFACE = &H80004002
    Const E_NOTIMPL = &H80004001
    Const E_OUTOFMEMORY = &H8007000E
    Const E_POINTER = &H80004003
    Const E_UNEXPECTED = &H8000FFFF
    Const S_OK = &H0
     
     
    Select Case lErrNum
    Case E_ABORT
        fnOLEError = " Aborted"
    Case E_ACCESSDENIED
        fnOLEError = " Access Denied"
    Case E_FAIL
        fnOLEError = " General Failure"
    Case E_HANDLE
        fnOLEError = " Bad/Missing Handle"
    Case E_INVALIDARG
        fnOLEError = " Invalid Argument"
    Case E_NOINTERFACE
        fnOLEError = " No Interface"
    Case E_NOTIMPL
        fnOLEError = " Not Implemented"
    Case E_OUTOFMEMORY
        fnOLEError = " Out of Memory"
    Case E_POINTER
        fnOLEError = " Invalid Pointer"
    Case E_UNEXPECTED
        fnOLEError = " Unknown Error"
    Case S_OK
        fnOLEError = " Success!"
    End Select
     
     
End Function

Then your calling code in a userform is like this:
Code:
    Range("A1:E100").CopyPicture xlScreen, xlBitmap
me.image1.picture = pastepicture(xlBitmap)
 
Upvote 0

Excel Facts

Last used cell?
Press Ctrl+End to move to what Excel thinks is the last used cell.
All I can say is AWESOME! The code works great. I assign the code in the userform to a commandbutton and pressing the button allows me to load the range into the userform as a picture. Thanks Rory!

Does this code works with any other version of excel and windows 7/8 32 bit and 64 bit?

Some of the intended users run on different Windows OS and I would like to maintain some backwards compatibility up to Excel 2003 and WinXP if possible.


Edit: This wonderful code should be made as a sticky or something. Just great code!!
 
Last edited:
Upvote 0
It should work on pretty much all Excel versions and any OS from XP onwards I think.
 
Upvote 0
My mistake and apologies to Mr. Bullen. The code posted was what I was referring to. There are a couple of amendments that I have found that are required for the code to work with all versions of office (haven't tried 365 yet).
I think it's 2007 that doesn't like the following...
Code:
Range("A1:E100").CopyPicture xlScreen, xlBitmap
'Let XL decide copy format
Range("A1:E100").Copy
Which maybe why seperate declaration sections are in the above code for XL07 (maybe not needed?)
I also encountered clipboard problems which resolve with the following...
Code:
 Private Declare Function EmptyClipboard Lib "user32" () As Long
Which you insert in the declarations section at top of the module. Then before the line of code to close the clipboard, insert the following line of code in the PastePicture function...
Code:
'clear then close clipboard
            EmptyClipboard
            H = CloseClipboard  'Release the clipboard to other programs
HTH.Dave
 
Upvote 0
I googled some research and the code adjustments are for VBA7 32 vs 64 bit accomodation thing. Maybe it was the XL2010 when the copypicture thing stopped working. Anyways, the code I posted works for all versions of XL including 2010 (not clear on the 32 vs 64 bit thing though). Dave
 
Upvote 0
The STEPHEN BULLEN's code generates a runtime error "Out of memory" when trying to save the picture to disk via the stdole.SavePicture Method .... Do any of you experience that problem ?

Tested on Excel2007 Win XP
 
Upvote 0
I only ran one quick test saving to disk yesterday (Office2013 64bit / Win 7) but didn't have a problem. Does it happen with any range?
 
Upvote 0
I only ran one quick test saving to disk yesterday (Office2013 64bit / Win 7) but didn't have a problem. Does it happen with any range?
It happens with any range . Weirdly enough, saving shapes to disk works but not ranges
I have googled on this and some users have reported this problem as well
 
Upvote 0

Forum statistics

Threads
1,215,580
Messages
6,125,654
Members
449,245
Latest member
PatrickL

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