Refer to oleobject picture in worksheet from VBA

Jaymond Flurrie

Well-known Member
Joined
Sep 22, 2008
Messages
919
Office Version
  1. 365
Platform
  1. Windows
I want a picture in a form take it's picture (i.e. the actual image) from either of the two oleobject images I've saved into a workbook.

The pictures (picArrowUp / picArrowDown) are in sheet shtVar and the image element in the form is imgTrend

so
Code:
imgTrend.Picture = shtVar.OLEObjects.Picture("picArrowUp")

which results as "Object doesn't support this property or method.

I'm pretty sure I'm not far from working code, but could you solve the last bit for me?

Thanks
 

Excel Facts

Select all contiguous cells
Pressing Ctrl+* (asterisk) will select the "current region" - all contiguous cells in all directions.
Not as close as you think. The probblem is that the .Picture property is looking for a valid iPicture object, which the OLE object is most certainly not. The bottom line is that you need to perform a series of messy conversions to get the OLE object into the proper format to satisfy what the .Picture property is looking for. I have seen several ways of doing this... The cleanest and most "turnkey" solution I have seen is from Stephen Bullen. In his method, use the .copypicture method of the Worksheet.Shapes collection, to get the picture onto teh clipboard, then his code takes that and turns it into an iPicture object that can then be passed to the .Picture roperty of the image control.

Userform Class Module:
Rich (BB code):
shtVar.Shapes("picArrowUp").CopyPicture

Set Me.imgTrend.Picture = PastePicture

Standard Code Module:
Rich (BB code):
'***************************************************************************
'*
'* MODULE NAME:     Paste Picture
'* AUTHOR & DATE:   STEPHEN BULLEN, Office Automation Ltd
'*                  15 November 1998
'*
'* CONTACT:         Stephen@oaltd.co.uk
'* WEB SITE:        http://www.oaltd.co.uk
'*
'* 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, just copy this module into your project, then you can use:
'*                      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 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
 
Upvote 0
Code:
imgTrend.Picture = shtVar.OLEObjects.Picture("picArrowUp")

I'm pretty sure I'm not far from working code, but could you solve the last bit for me?

Code:
imgTrend.Picture = shtVar.OLEObjects("picArrowUp").Object.Picture

Don't know if anything has changed through the 5 year gap (I use Excel 2013), but I was looking for the same thing and found the answer in a newer thread:
https://www.mrexcel.com/forum/excel...erform-image-vba-post4013892.html#post4013892
Posted because Google finds this thread, and the answer from hatman could be misleading.
 
Upvote 0
That is a slick solution. Thank you for updating this thread Rorin. Since I still use the solution from Stephen Bullen above, I'll be reviewing several of my projects and replacing the "messy" solution with the one you linked to. I always like to simplify!!!
 
Upvote 0
Just a reminder that the solution posted by rorin will not work for non-ole shapes .. In order to paste the image of a non-ole shape or of a range etc into a userform or into a control, you will still need to use the API workaround.
 
Upvote 0
I hadn't looked closely, but I suspected that there would be cases where the API solution would still be necessary. Off the top of your head, Jaafar, will the simpler solution work with passing an image to the getImage Callback of a Ribbon Control? Right now I am using the API approach for this case... worth investigating the simpler approach? I can never remember which image formats are used in what objects (shrug) I always need to either research or trial-and-error.
 
Upvote 0
I hadn't looked closely, but I suspected that there would be cases where the API solution would still be necessary. Off the top of your head, Jaafar, will the simpler solution work with passing an image to the getImage Callback of a Ribbon Control? Right now I am using the API approach for this case... worth investigating the simpler approach? I can never remember which image formats are used in what objects (shrug) I always need to either research or trial-and-error.
Hi hatman,

I am afraid, I have very little experience with programming the Ribbon so I couldn't advise you there ... Maybe other members of this forum can help you with that question.

The fact that one cannot flexibly program the ribbon directly from VBA as it used to be with the old excel menus put me off further exploring that area .

I am planning to start exploring this area of excel (and office) in some depth.
 
Upvote 0
Understood. Yeah, the Ribbon was a big paradigm shift... good luck. I'll probably trial-and-error this when I get a chance, unless someone chimes in. I'll share my results here once I have looked at it in more detail.
 
Upvote 0
Both approaches return the same IPicture type, so they should work. The main issue, as Jaafar noted, is that you'd have to store your pictures in Image controls on a worksheet, which tends to bloat file sizes.
 
Upvote 0

Forum statistics

Threads
1,215,650
Messages
6,126,010
Members
449,280
Latest member
Miahr

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