copy image from Excel to mspaint

plawson

New Member
Joined
May 25, 2009
Messages
4
I'm trying to copy an image ("Picture 1") from an Excel worksheet into mspaint so that I can save the image as a file and call it into the footer of my Excel worksheet. I can open MSPaint but can't seem to paste it. Here's my code:

Dim ReturnValue
ActiveSheet.Shapes("Picture 1").Select
Selection.Copy
ReturnValue = Shell("C:\WINDOWS\system32\mspaint.exe")
SendKeys "^V", True

Please help.
 

Excel Facts

Which came first: VisiCalc or Lotus 1-2-3?
Dan Bricklin and Bob Frankston debuted VisiCalc in 1979 as a Visible Calculator. Lotus 1-2-3 debuted in the early 1980's, from Mitch Kapor.
Press PrtScr, open Paint and then paste.
 
Upvote 0
Hi Norrie,

I have been looking for a solution to this, I think plawson is trying to copy a picture held within the spreadsheet to paint in which case selecting the picture and using CTRL+C then CTRL+V works manually. However I have still not managed to find any code to do the CTRL+V into Paint or even save the Excel picture directly as a .bmp image.
 
Upvote 0
OK, follow me on this, to accomplish this requires the genius code of Stephen Bullen and then tapping into it to fit your situation.


In a new fresh standard module, paste in these Functions exactly as I repost them here, taken from one of Stephen's downloadable files.


Code:
Option Explicit
Option Compare Text
 
''' 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
'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
 
'''Windows API Function Declarations
'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
'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
'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
''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''
''' 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
''' --------------------------------------------------------------------------
''' 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
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
    '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
'''
 
Private Function CreatePicture(ByVal hPic As Long, ByVal hPal As Long, ByVal lPicType) As IPicture
 
' 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, True, 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



Next, in a new fresh standard module, paste this in:

Code:
Sub PaystePicture()
Dim fname$, objPicture As Variant
With ActiveSheet.Shapes("Picture 1")
.CopyPicture xlScreen, xlBitmap
Set objPicture = PastePicture(xlBitmap)
fname = ThisWorkbook.Path & "\" & .Name & ".bmp"
End With
SavePicture objPicture, fname
End Sub


I know this works because I just tested it. Assuming the sheet with Picture 1 is the active sheet (if it isn't, just substitute "ActiveSheet" with the worksheet name in the above macro), this will copy the picture named "Picture 1" that you've inserted on your worksheet and paste it as a bmp file in the same path as your host workbook.

From there you can insert the picture into your footer as you said was your ultimate goal.

Thanks again to Stephen Bullen for the API functions that makes this possible.
 
Upvote 0
Wow Tom! That's much more complicated than I thought. When I tried this I received a compile error ("only comments may appear after End Sub, End Function, End Property").

Any ideas?

(P.S. Thanks for your help.)
 
Upvote 0
Greetings plawson,

There will be no errors if you copied Tom's code as is. I just tested in 2000, works flawlessly.

Far, far less brilliant, and mentioned only if a simple way to get a gif is wanted:

<font face=Courier New><SPAN style="color:#00007F">Option</SPAN> <SPAN style="color:#00007F">Explicit</SPAN><br><br><SPAN style="color:#00007F">Sub</SPAN> SavePic2GIF()<br><SPAN style="color:#00007F">Dim</SPAN> shp         <SPAN style="color:#00007F">As</SPAN> Shape<br><SPAN style="color:#00007F">Dim</SPAN> cht         <SPAN style="color:#00007F">As</SPAN> ChartObject<br><SPAN style="color:#00007F">Dim</SPAN> strPath     <SPAN style="color:#00007F">As</SPAN> <SPAN style="color:#00007F">String</SPAN><br>        <br>    strPath = ThisWorkbook.Path & Application.PathSeparator<br>        <br>    <SPAN style="color:#00007F">With</SPAN> ActiveSheet<br>            <br>        <SPAN style="color:#00007F">Set</SPAN> shp = .Shapes("Picture 1")<br>        shp.CopyPicture xlScreen, xlPicture<br>        <SPAN style="color:#007F00">'//  Depending on what's in the pic, you may need to add a few points to</SPAN><br>        <SPAN style="color:#007F00">'// hgt/wid</SPAN><br>        <SPAN style="color:#00007F">Set</SPAN> cht = .ChartObjects.Add(0, 0, shp.Width, shp.Height)<br>        cht.Chart.Paste<br>        cht.Chart.Export strPath & shp.Name & ".gif"<br>        cht.Delete<br>    <SPAN style="color:#00007F">End</SPAN> <SPAN style="color:#00007F">With</SPAN><br>        <br>    <SPAN style="color:#00007F">Set</SPAN> shp = <SPAN style="color:#00007F">Nothing</SPAN><br>    <SPAN style="color:#00007F">Set</SPAN> cht = <SPAN style="color:#00007F">Nothing</SPAN><br>        <br><SPAN style="color:#00007F">End</SPAN> <SPAN style="color:#00007F">Sub</SPAN><br></FONT>


Mark

PS - could you post the code as you tried it? Not the first module with the API, just the second module.
 
Last edited:
Upvote 0
Thanks Tom. Not sure what I did wrong the first time but I tried your code again and it worked.
 
Upvote 0

Forum statistics

Threads
1,220,965
Messages
6,157,119
Members
451,398
Latest member
rjsteward

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