Load Image to User Form

FracinDean

Board Regular
Joined
Jul 11, 2011
Messages
110
Office Version
  1. 365
Platform
  1. Windows
Mr. Excel Forum Members,

I am trying to do something similar to what was described in another thread on this forum, Show worksheet range of cells in a User Form. In my case, I'm trying to copy a named range in my workbook and paste it as a picture into a user form. As far as I can figure out, there are 5 things I must do to get this to work

1) Add a Class module with the code mentioned in the linked thread. Done.
2) Add a user form. I added a user form called "myLegend".
3) Write a sub to copy the desired image to the clipboard. Step 3 has been coded and tested by running the sub below and then manually pasting the image, but here is the code for information:
VBA Code:
Sub CopyImageToCBoard()
    Application.CutCopyMode = False
    With Worksheets("Steward Data")
        Range("theLegend").CopyPicture Appearance:=xlScreen, Format:=xlPicture
    End With
End Sub

4) Add a procedure to initialize the form:

VBA Code:
Sub loadLegend()       
    Load myLegend
End Sub

5) Add the code to the UserForm module to execute whenever the form is initialized.

VBA Code:
Private Sub UserForm_Initialize()       'goes in the UserForm code module for form 'myLegend'
    Application.ScreenUpdating = False          'Turn off screen updating
    Call CopyImageToCBoard         'sub that copies the desired range to the clipboard
    With Me.Image1
        .Picture = LoadPicture(vbNullString)    ' clear existing picture
        .Picture = PastePicture(xlPicture)      ' paste range of info copied
    End With
    Application.ScreenUpdating = True           'Turn on screen updating
    myLegend.Show
End Sub

When I run the procedure loadLegend(), I'm getting a compile error on the "With Me.Legend1" statement in the Userform_Initialize procedure, The error message says "Method or data member not found."

I don't know how to fix this error. Any assistance would be appreciated.
 
@rlv01, I made a workbook to test this with nothing else in it except the essential elements: 1) a named range with my image on Sheet1, 2) the copy and load macros in Module1, 3) the Stephen Bullen code in Class1, and 4) UserForm1 with an empty image control and the code I showed before in the form code module. I get the same error. I am able to share the 31.0 kb macro-enabled test workbook if you want to try it.
 
Upvote 0

Excel Facts

Excel motto
Not everything I do at work revolves around Excel. Only the fun parts.
@rlv01 I figured out how to make this work, but I don't understand why. I moved the Stephen Bullen code to my "Module1" and removed the class module that I had inserted. Now the code is working. I don't understand the purpose of Class modules vs. other modules. Thank you for your help.
 
Upvote 0
Thank you for your patience and your many replies to this thread. I have a Class module with the Stephen Bullen code. I also checked that I have a reference to the OLE_Automation in my project.

The OLE_Automation reference is pointing to C:\Windows\SysWOW64\stdole2.tlg. That name sounds like it could be expecting a 64-bit computer, but I have a 32-bit computer, so I don't know if there could be some incompatibility there.

Is there more than one source to obtain the Stephen Bullen code? I am wondering if the version of it that I have could have something wrong with it. When I copied and pasted it into my Class module, there was a single quote in the code that was creating an error message, and the error went away when I got rid of that, but it makes me wonder if the code I have could be corrupted in some other way.
I don't think the Bullen code needs to be in a class module. Just put it in a standard code module.
 
Upvote 0
VBA Code:
Option Explicit
'***************************************************************************
'*
'* 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 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

Forum statistics

Threads
1,214,920
Messages
6,122,272
Members
449,075
Latest member
staticfluids

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