/
Using Macro in Excel to match SKUs and Images

Using Macro in Excel to match SKUs and Images

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_Debug() 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 moveFiles As Boolean Dim lastSearchFolder As String Dim lastCopyFolder As String Dim debugOutput 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 = Trim(CStr(cell.Value)) ' Trim spaces 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 or move the found files response = MsgBox("Do you want to copy or move the found files to a new folder?" & vbCrLf & _ "Yes = Copy, No = Move, Cancel = Exit", vbYesNoCancel + vbQuestion, "File Operation") If response = vbCancel Then Exit Sub moveFiles = (response = vbNo) ' 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 ' Initialize debugging output debugOutput = "Debug Output:" & vbCrLf ' Move or copy matched files Dim processedFilesDict As Object Set processedFilesDict = CreateObject("Scripting.Dictionary") Dim filePath As Variant For Each cell In rng.Cells baseFilename = Trim(CStr(cell.Value)) ' Trim spaces If filenamesDict.exists(baseFilename) Then For Each filePath In filenamesDict(baseFilename) If Not processedFilesDict.exists(filePath) Then debugOutput = debugOutput & "Matched File: " & filePath & vbCrLf If fso.FileExists(filePath) Then ' Ensure the file exists If moveFiles Then debugOutput = debugOutput & "Moving to: " & destFolderPath & "\" & fso.GetFileName(filePath) & vbCrLf fso.MoveFile filePath, destFolderPath & "\" & fso.GetFileName(filePath) Else debugOutput = debugOutput & "Copying to: " & destFolderPath & "\" & fso.GetFileName(filePath) & vbCrLf fso.CopyFile filePath, destFolderPath & "\" & fso.GetFileName(filePath), True End If processedFilesDict.Add filePath, True Else debugOutput = debugOutput & "File not found: " & filePath & vbCrLf End If End If Next filePath Else debugOutput = debugOutput & "No match for: " & baseFilename & vbCrLf End If Next cell ' Output debugging information ' Debug.Print debugOutput ' MsgBox debugOutput, vbInformation, "Debugging Information" 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 = Trim(Split(fileObj.Name, ".")(0)) ' Trim spaces from base filename 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 ' Ensure the range is valid by wrapping the folderPath as a valid Excel string literal 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

 

Related content

Using an Excel Macro to match product SKU names
Using an Excel Macro to match product SKU names
More like this
Simple Product image SKU Matching using COUNTIF method in Excel
Simple Product image SKU Matching using COUNTIF method in Excel
More like this
Simple product name SKU checking using Conditional Formatting only
Simple product name SKU checking using Conditional Formatting only
More like this
SKU Error Matching in excel
SKU Error Matching in excel
More like this
How to match/check product SKU IDs for Product Data Template
How to match/check product SKU IDs for Product Data Template
More like this
1- Product Data.xlsx
1- Product Data.xlsx
More like this

©2020 ConceptSauce ltd / For further help please contact us directly on Team@conceptsauce.io