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:


I tried this code and it works great except that the png file it generates is so much larger in size than copying the range to MS-paint then saving it as a png.
For example, I have a simple 10*10 text range. This code generated a 600k png, while copy-pasting to MS-paint generates a 30k one, with the same quality.

(note: I am using .CopyPicture xlBitmap rather than xlPicture as the later generates a broken image file).

Is there a way to reduce the size in Bullen's code?
Thanks.
 
Last edited:
Upvote 0

Excel Facts

Select all contiguous cells
Pressing Ctrl+* (asterisk) will select the "current region" - all contiguous cells in all directions.
I tried this code and it works great except that the png file it generates is so much larger in size than copying the range to MS-paint then saving it as a png.
For example, I have a simple 10*10 text range. This code generated a 600k png, while copy-pasting to MS-paint generates a 30k one, with the same quality.

(note: I am using .CopyPicture xlBitmap rather than xlPicture as the later generates a broken image file).

Is there a way to reduce the size in Bullen's code?
Thanks.


xlPicture generates a much smaller file but the image is broken with error message: "Windows Photo Viewer can't open this picture because the file appears to be damaged or corrupt".

Is there a way to fix the error for xlPicture?
Thanks a lot.
 
Upvote 0
I guess my reply was somewhat cryptic. Here's my adaptation of Mr. Bullen's code. HTH. Dave
Module code....
Code:
'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
    
    '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 Integer) 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 Integer) As Long
    'Close the clipboard
    Private Declare Function CloseClipboard Lib "user32" () As Long
    Private Declare Function EmptyClipboard 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.
    Private 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.
    Private 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
    
    'The API format types we're interested in
    Public Const CF_BITMAP = 2
    Public Const CF_PALETTE = 9
    Public Const CF_ENHMETAFILE = 14
    Public Const IMAGE_BITMAP = 0
    Public Const LR_COPYRETURNORG = &H4
    
    'OLE Picture types
    Public Const PICTYPE_BITMAP = 1
    Public Const PICTYPE_ENHMETAFILE = 4
'======================================================================================================

Public Function PastePicture(Optional lXlPicType As Long = xlPicture) As IPicture
    Dim h As Long, hPicAvail As Long, hPtr As Long, hPal As Long, lPicType As Long, hCopy 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
        h = OpenClipboard(0&)   'Get access to the clipboard
        If h > 0 Then
            hPtr = GetClipboardData(lPicType) 'Get a handle to the image data
            
            '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
            
           'clear then close clipboard
            EmptyClipboard

            h = CloseClipboard  'Release the clipboard to other programs
            
            '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

Private Function CreatePicture(ByVal hPic As Long, ByVal hPal As Long, ByVal lPicType) As IPicture
    Dim r As Long, uPicInfo As uPicDesc, IID_IDispatch As GUID, IPic As IPicture
    
    ' 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, True, IPic)
    Set CreatePicture = IPic    ' Return the new Picture object.
End Function

To make a picture file of a range (and any shapes etc. in it)....
Code:
Sub Test()
Dim Objtargetrange As Range
With Sheets("Sheet1")
    Set Objtargetrange = .Range(.Cells(1, "A"), .Cells(10, "D"))
End With
Objtargetrange.Copy
SavePicture PastePicture(CF_BITMAP), "C:\test\myPic.png"
End Sub
 
Upvote 0
NdNoviceHlp,

Thanks a lot for the code but it reports an error saying it needs modification (such as for the Declares) for 64bit Excel.
May I know how that modification can be done?

Thanks again.
 
Upvote 0
Run the code on 32 bit instal only. Trial it to see if it suits your needs. But U need to make the API's ptrsafe (which I would also appreciate for the code I posted if anyone has the time/know how available.) Anyways, U never mentioned the 64 bit part and I sort of forgot about the 32 bit API thing being nb. The 64 bit conversion is doable but not by me. Good luck. Dave
 
Upvote 0

Forum statistics

Threads
1,216,522
Messages
6,131,146
Members
449,626
Latest member
Stormythebandit

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