Skip to end of metadata
Go to start of metadata

You are viewing an old version of this content. View the current version.

Compare with Current View Version History

« Previous Version 10 Next »

In the below video you will see how you can use the macro here to find out what images exist/match the SKU code provided in the Excel file:

Creating an Excel VBA macro to accomplish the tasks you've described would involve several steps. Here's a step-by-step guide on how to create such a macro:

  1. Open Excel and press Alt + F11 to open the Visual Basic for Applications (VBA) editor.

  2. In the VBA editor, right-click on "VBAProject (Your Workbook Name)" in the Project Explorer on the left and select "Insert" -> "Module" to insert a new module.

  3. Copy and paste the following VBA code into the module:

Sub ConceptSauce_ImageMatchHelper()
    Dim folderPath As String
    Dim destFolderPath As String
    Dim ws As Worksheet
    Dim rng As Range
    Dim cell As Range
    Dim fso As Scripting.FileSystemObject
    Dim filenamesDict As Object
    Dim baseFilename As String
    Dim response As VbMsgBoxResult
    Dim lastSearchFolder As String
    Dim lastCopyFolder As String

    ' Set default folder paths from named ranges, if available
    On Error Resume Next
    lastSearchFolder = ThisWorkbook.Names("LastSearchFolder").RefersToRange.Value
    lastCopyFolder = ThisWorkbook.Names("LastCopyFolder").RefersToRange.Value
    On Error GoTo 0

    ' Prompt user for the folder
    With Application.FileDialog(msoFileDialogFolderPicker)
        .Title = "Select a Folder to Search"
        .InitialFileName = lastSearchFolder
        .AllowMultiSelect = False
        If .Show = -1 Then
            folderPath = .SelectedItems(1)
            ' Save the selected folder path
            SetNamedRange "LastSearchFolder", folderPath
        Else
            Exit Sub
        End If
    End With

    ' Create filesystem object
    Set fso = New Scripting.FileSystemObject

    ' Create a dictionary to store file paths by base filename
    Set filenamesDict = CreateObject("Scripting.Dictionary")
    AddFilesRecursively fso.GetFolder(folderPath), filenamesDict

    ' Get the active worksheet
    Set ws = ThisWorkbook.ActiveSheet

    ' Ask user to select the column to match
    On Error Resume Next
    Set rng = Application.InputBox("Select a range", "Select cells with filenames to match", Type:=8)
    On Error GoTo 0
    If rng Is Nothing Or rng.Cells.Count = 0 Then Exit Sub

    ' Color-code cells based on filename matches
    For Each cell In rng.Cells
        baseFilename = CStr(Trim(cell.Value))
        If PartialMatchExists(baseFilename, filenamesDict) Then
            cell.Interior.Color = RGB(0, 255, 0) ' Green
        Else
            cell.Interior.Color = RGB(255, 0, 0) ' Red
        End If
    Next cell

    ' Ask the user if they want to copy the found files
    response = MsgBox("Do you want to copy the found files to a new folder?", vbYesNo + vbQuestion, "Copy Files")
    If response = vbYes Then
        ' Prompt for destination folder and set initial path
        With Application.FileDialog(msoFileDialogFolderPicker)
            .Title = "Select a Destination Folder"
            .InitialFileName = lastCopyFolder
            .AllowMultiSelect = False
            If .Show = -1 Then
                destFolderPath = .SelectedItems(1)
                ' Save the destination folder path
                SetNamedRange "LastCopyFolder", destFolderPath
            Else
                Exit Sub
            End If
        End With

        ' Copy matched files, ensuring only unique paths are added
        Dim copiedFilesDict As Object
        Set copiedFilesDict = CreateObject("Scripting.Dictionary")
        Dim filePath As Variant
        For Each cell In rng.Cells
            baseFilename = CStr(Trim(cell.Value))
            If filenamesDict.exists(baseFilename) Then
                For Each filePath In filenamesDict(baseFilename)
                    If Not copiedFilesDict.exists(filePath) Then
                        fso.CopyFile filePath, destFolderPath & "\" & fso.GetFileName(filePath), True
                        copiedFilesDict.Add filePath, True
                    End If
                Next filePath
            End If
        Next cell
    End If

    MsgBox "Process complete!", vbInformation, "Done"
End Sub

' Optimized recursive subroutine to add files from folder and subfolders
Sub AddFilesRecursively(folder As Scripting.folder, filenamesDict As Object)
    Dim fileObj As Scripting.File
    Dim subfolder As Scripting.folder
    Dim baseFilename As String

    For Each fileObj In folder.Files
        If InStr(fileObj.Name, ".jpg") > 0 Or InStr(fileObj.Name, ".png") > 0 Then
            baseFilename = Split(fileObj.Name, "_")(0)
            If Not filenamesDict.exists(baseFilename) Then
                Set filenamesDict(baseFilename) = New Collection
            End If
            filenamesDict(baseFilename).Add fileObj.Path
        End If
    Next fileObj

    For Each subfolder In folder.Subfolders
        AddFilesRecursively subfolder, filenamesDict
    Next subfolder
End Sub

' Helper function for partial matches
Function PartialMatchExists(baseFilename As String, filenamesDict As Object) As Boolean
    Dim key As Variant
    PartialMatchExists = False
    For Each key In filenamesDict.Keys
        If Left(key, Len(baseFilename)) = baseFilename Then
            PartialMatchExists = True
            Exit Function
        End If
    Next key
End Function

' Function to set or update a named range with folder path
Sub SetNamedRange(rangeName As String, folderPath As String)
    On Error Resume Next
    ThisWorkbook.Names.Add Name:=rangeName, RefersTo:="='" & folderPath & "'"
    On Error GoTo 0
End Sub
  1. Close the VBA editor and return to your Excel workbook.

  2. To run the macro, press Alt + F8 to open the "Macro" dialog, select "CheckFileNames," and click "Run."

  3. Make sure to enable the correct reference.

    1. Go to References: In the VBA editor, go to Tools > References.

    2. Find and Enable "Microsoft Scripting Runtime": Scroll through the list of available references, check the box next to "Microsoft Scripting Runtime", and click OK.

Here is a video to show this in action (smile)

Excel Macro to match SKU codes with file names.mp4

  • No labels