VBA to Check for Duplicates and add Nonduplicate

Squid1622

Registered User.
Local time
Yesterday, 21:08
Joined
May 14, 2012
Messages
49
So I'm attempting to do something I'm not really sure how to accomplish. Essentially I'm adding file names from a folder to a table using the code found here: http://www.allenbrowne.com/ser-59alt.html In this code, I need it to check against the table for duplicates before adding records and only add records that are not currently in the table.

Code:
Option Compare Database
Option Explicit

'list files to tables
'http://allenbrowne.com/ser-59alt.html

Dim gCount As Long ' added by Crystal

Sub runListFiles()
    'Usage example.
    Dim strPath As String _
    , strFileSpec As String _
    , booIncludeSubfolders As Boolean
    
    strPath = "E:\"
    strFileSpec = "*.*"
    booIncludeSubfolders = True
    
    ListFilesToTable strPath, strFileSpec, booIncludeSubfolders
End Sub

'crystal modified parameter specification for strFileSpec by adding default value
Public Function ListFilesToTable(strPath As String _
    , Optional strFileSpec As String = "*.*" _
    , Optional bIncludeSubfolders As Boolean _
    )
On Error GoTo Err_Handler
    'Purpose:   List the files in the path.
    'Arguments: strPath = the path to search.
    '           strFileSpec = "*.*" unless you specify differently.
    '           bIncludeSubfolders: If True, returns results from subdirectories of strPath as well.
    'Method:    FilDir() adds items to a collection, calling itself recursively for subfolders.
    
    Dim colDirList As New Collection
    Dim varitem As Variant
    Dim rst As DAO.Recordset
    
   Dim mStartTime As Date _
      , mSeconds As Long _
      , mMin As Long _
      , mMsg As String
      
   mStartTime = Now()
   '--------
    
    Call FillDirToTable(colDirList, strPath, strFileSpec, bIncludeSubfolders)
      
   mSeconds = DateDiff("s", mStartTime, Now())
   
   mMin = mSeconds \ 60
   If mMin > 0 Then
      mMsg = mMin & " min "
      mSeconds = mSeconds - (mMin * 60)
   Else
      mMsg = ""
   End If
   
   mMsg = mMsg & mSeconds & " seconds"
   
   MsgBox "Done adding " & Format(gCount, "#,##0") & " files from " & strPath _
      & IIf(Len(Trim(strFileSpec)) > 0, " for file specification --> " & strFileSpec, "") _
      & vbCrLf & vbCrLf & mMsg, , "Done"
  
Exit_Handler:
   SysCmd acSysCmdClearStatus
   '--------
    
    Exit Function

Err_Handler:
    MsgBox "Error " & Err.Number & ": " & Err.Description, , "ERROR"
    
    'remove next line after debugged -- added by Crystal
    Stop: Resume 'added by Crystal
    
    Resume Exit_Handler
End Function

Private Function FillDirToTable(colDirList As Collection _
    , ByVal strFolder As String _
    , strFileSpec As String _
    , bIncludeSubfolders As Boolean)
   
    'Build up a list of files, and then add add to this list, any additional folders
    On Error GoTo Err_Handler
    
    Dim strTemp As String
    Dim colFolders As New Collection
    Dim vFolderName As Variant
    Dim strSQL As String

    'Add the files to the folder.
    strFolder = TrailingSlash(strFolder)
    strTemp = Dir(strFolder & strFileSpec)
    Do While strTemp <> vbNullString
         gCount = gCount + 1
         SysCmd acSysCmdSetStatus, gCount
         strSQL = "INSERT INTO Files " _
          & " (FName, FPath) " _
          & " SELECT """ & strTemp & """" _
          & ", """ & strFolder & """;"
         CurrentDb.Execute strSQL
        colDirList.Add strFolder & strTemp
        strTemp = Dir
    Loop

    If bIncludeSubfolders Then
        'Build collection of additional subfolders.
        strTemp = Dir(strFolder, vbDirectory)
        Do While strTemp <> vbNullString
            If (strTemp <> ".") And (strTemp <> "..") Then
                If (GetAttr(strFolder & strTemp) And vbDirectory) <> 0& Then
                    colFolders.Add strTemp
                End If
            End If
            strTemp = Dir
        Loop
        'Call function recursively for each subfolder.
        For Each vFolderName In colFolders
            Call FillDirToTable(colDirList, strFolder & TrailingSlash(vFolderName), strFileSpec, True)
        Next vFolderName
    End If

Exit_Handler:
    
    Exit Function

Err_Handler:
    strSQL = "INSERT INTO Files " _
    & " (FName, FPath) " _
    & " SELECT ""  ~~~ ERROR ~~~""" _
    & ", """ & strFolder & """;"
    CurrentDb.Execute strSQL
    
    Resume Exit_Handler
End Function

Public Function TrailingSlash(varIn As Variant) As String
    If Len(varIn) > 0& Then
        If Right(varIn, 1&) = "\" Then
            TrailingSlash = varIn
        Else
            TrailingSlash = varIn & "\"
        End If
    End If
End Function
My thought is that the code needs to go right before this piece of code:

Code:
Err_Handler:
    strSQL = "INSERT INTO Files " _
    & " (FName, FPath) " _
    & " SELECT ""  ~~~ ERROR ~~~""" _
    & ", """ & strFolder & """;"
    CurrentDb.Execute strSQL
    
    Resume Exit_Handler
End Function
How do I force the recordset to check itself against the table it's trying to load into before actually inputting the data into the table?
 
Last edited:
Not sure about your overall purpose, but do you need a table that shows all the files in a particular folder? If so, just delete everything from that table, and insert everything you find in the folder.

Then you have no conflicts and it's fast and simple.
 
Eventually I will connect this table to a query in order to generate a list box on a form. The query will link the files in this table with their "master records" in a different table. Because of this I can't delete the records each time. In the long run, the query based on this table will power an automatically updated selectable list/combobox.
 
Last edited:
I would test if the file exists in the table before the insert rather than wait for the error. Maybe add an If...End If block, in blue below, that only does the insert if the file is not found . . .
Code:
   [COLOR="Green"] 'Add the files to the folder.[/COLOR]
    strFolder = TrailingSlash(strFolder)
    strTemp = Dir(strFolder & strFileSpec)
    Do While strTemp <> vbNullString
[COLOR="Blue"]         If Not DCount("*", "Files", "FName = '" & strTemp & "'") Then
[/COLOR]           [COLOR="Green"] 'only inserts the file if it doesn't already exist[/COLOR]
            gCount = gCount + 1
            SysCmd acSysCmdSetStatus, gCount
            strSQL = "INSERT INTO Files " _
             & " (FName, FPath) " _
             & " SELECT """ & strTemp & """" _
             & ", """ & strFolder & """;"
            CurrentDb.Execute strSQL
            colDirList.Add strFolder & strTemp
[COLOR="Blue"]        End If[/COLOR]
        strTemp = Dir
    Loop
Makes sense?
 
The solution makes sense in theory. When I implemented it though, it appears that the dcount is not preventing the the duplicate files from being loaded into the table. Is there something in the Dcount that I need specify that I'm not? All I did was copy and paste your solution above, so I'm not sure if there are criteria I'm supposed to be putting in.
 
What I posted just describes the principle. You may need to modify that DCount() critieria, like taking a 2nd look, you have FName AND FPath in the table, so yeah, you probably need to check for both.
Code:
If Not DCount("*", "Files", "FName = '" & strTemp & "' [COLOR="Blue"]AND FPath = '" & somevalue & "'"[/COLOR]) Then
Gotta run,
 
:banghead:So I've been trying to get the DCount to work for the last 3 hours or so and I can't figure it out. Not matter which way I try it, it doesn't prevent the code from uploading duplicate files. Is there a simpler way to do this thanthe Allanbrowne code? I really don't care about listing subfolders since everything is going to stay in one folder location
 
Does this work?
Code:
[COLOR="Green"]    'Add the files to the folder.[/COLOR]
    strFolder = TrailingSlash(strFolder)
    strTemp = Dir(strFolder & strFileSpec)
    Do While strTemp <> vbNullString
[COLOR="Green"]         'count existing records with this FName and FPath[/COLOR]
         If DCount("*", "Files", "FName = '" & [COLOR="Indigo"]strTemp[/COLOR] & "' AND FPath = '" & [COLOR="Red"]strFolder[/COLOR] & "'") = 0 Then
[COLOR="Green"]            'insert only if there are none[/COLOR]
            gCount = gCount + 1
            SysCmd acSysCmdSetStatus, gCount
            strSQL = "INSERT INTO Files " _
             & " (FName, FPath) " _
             & " SELECT """ & [COLOR="Purple"]strTemp[/COLOR] & """" _
             & ", """ & [COLOR="Red"]strFolder[/COLOR] & """;"
            CurrentDb.Execute strSQL
            colDirList.Add strFolder & strTemp
        End If
        strTemp = Dir
    Loop
 
without using dcount, you can create compound index with no duplicate.
 
Does this work?
Code:
[COLOR=green]    'Add the files to the folder.[/COLOR]
    strFolder = TrailingSlash(strFolder)
    strTemp = Dir(strFolder & strFileSpec)
    Do While strTemp <> vbNullString
[COLOR=green]        'count existing records with this FName and FPath[/COLOR]
         If DCount("*", "Files", "FName = '" & [COLOR=indigo]strTemp[/COLOR] & "' AND FPath = '" & [COLOR=red]strFolder[/COLOR] & "'") = 0 Then
[COLOR=green]           'insert only if there are none[/COLOR]
            gCount = gCount + 1
            SysCmd acSysCmdSetStatus, gCount
            strSQL = "INSERT INTO Files " _
             & " (FName, FPath) " _
             & " SELECT """ & [COLOR=purple]strTemp[/COLOR] & """" _
             & ", """ & [COLOR=red]strFolder[/COLOR] & """;"
            CurrentDb.Execute strSQL
            colDirList.Add strFolder & strTemp
        End If
        strTemp = Dir
    Loop

That worked perfectly. Thank you sooooo much! I was beating my head against a wall and you kept me from being a bloody mess.
 
To everyone who might read this in the future. After all the help in this post, I felt it would be proper to post the whole code. This is now a modification of the code on the allen browne website. It will check the files in a folder and load them into a table, but will also remove any duplicates from being loaded.
Code:
 Option Compare Database
Option Explicit
 'list files to tables
'http://allenbrowne.com/ser-59alt.html
 Dim gCount As Long ' added by Crystal
 Sub runListFiles()
    'Usage example.
    Dim strPath As String _
    , strFileSpec As String _
    , booIncludeSubfolders As Boolean
    
    strPath = "E:\"
    strFileSpec = "*.*"
    booIncludeSubfolders = True
    
    ListFilesToTable strPath, strFileSpec, booIncludeSubfolders
End Sub
 'crystal modified parameter specification for strFileSpec by adding default value
Public Function ListFilesToTable(strPath As String _
    , Optional strFileSpec As String = "*.*" _
    , Optional bIncludeSubfolders As Boolean _
    )
On Error GoTo Err_Handler
    'Purpose:   List the files in the path.
    'Arguments: strPath = the path to search.
    '           strFileSpec = "*.*" unless you specify differently.
    '           bIncludeSubfolders: If True, returns results from subdirectories of strPath as well.
    'Method:    FilDir() adds items to a collection, calling itself recursively for subfolders.
    
    Dim colDirList As New Collection
    Dim varitem As Variant
    Dim rst As DAO.Recordset
    
   Dim mStartTime As Date _
      , mSeconds As Long _
      , mMin As Long _
      , mMsg As String
      
   mStartTime = Now()
   '--------
    
    Call FillDirToTable(colDirList, strPath, strFileSpec, bIncludeSubfolders)
      
   mSeconds = DateDiff("s", mStartTime, Now())
   
   mMin = mSeconds \ 60
   If mMin > 0 Then
      mMsg = mMin & " min "
      mSeconds = mSeconds - (mMin * 60)
   Else
      mMsg = ""
   End If
   
   mMsg = mMsg & mSeconds & " seconds"
   
   MsgBox "Done adding " & Format(gCount, "#,##0") & " files from " & strPath _
      & IIf(Len(Trim(strFileSpec)) > 0, " for file specification --> " & strFileSpec, "") _
      & vbCrLf & vbCrLf & mMsg, , "Done"
  
Exit_Handler:
   SysCmd acSysCmdClearStatus
   '--------
    
    Exit Function
 Err_Handler:
    MsgBox "Error " & Err.Number & ": " & Err.Description, , "ERROR"
    
    'remove next line after debugged -- added by Crystal
    Stop: Resume 'added by Crystal
    
    Resume Exit_Handler
End Function
 Private Function FillDirToTable(colDirList As Collection _
    , ByVal strFolder As String _
    , strFileSpec As String _
    , bIncludeSubfolders As Boolean)
   
    'Build up a list of files, and then add add to this list, any additional folders
    On Error GoTo Err_Handler
    
    Dim strTemp As String
    Dim colFolders As New Collection
    Dim vFolderName As Variant
    Dim strSQL As String
       'Add the files to the folder.
    strFolder = TrailingSlash(strFolder)
    strTemp = Dir(strFolder & strFileSpec)
    Do While strTemp <> vbNullString
         'count existing records with this FName and FPath
         If DCount("*", "Files", "FName = '" & strTemp & "' AND FPath = '" & strFolder & "'") = 0 Then
            'insert only if there are none
            gCount = gCount + 1
            SysCmd acSysCmdSetStatus, gCount
            strSQL = "INSERT INTO Files " _
             & " (FName, FPath) " _
             & " SELECT """ & strTemp & """" _
             & ", """ & strFolder & """;"
            CurrentDb.Execute strSQL
            colDirList.Add strFolder & strTemp
        End If
        strTemp = Dir
    Loop
     If bIncludeSubfolders Then
        'Build collection of additional subfolders.
        strTemp = Dir(strFolder, vbDirectory)
        Do While strTemp <> vbNullString
            If (strTemp <> ".") And (strTemp <> "..") Then
                If (GetAttr(strFolder & strTemp) And vbDirectory) <> 0& Then
                    colFolders.Add strTemp
                End If
            End If
            strTemp = Dir
        Loop
        'Call function recursively for each subfolder.
        For Each vFolderName In colFolders
            Call FillDirToTable(colDirList, strFolder & TrailingSlash(vFolderName), strFileSpec, True)
        Next vFolderName
    End If
 Exit_Handler:
    
    Exit Function
 Err_Handler:
    strSQL = "INSERT INTO Files " _
    & " (FName, FPath) " _
    & " SELECT ""  ~~~ ERROR ~~~""" _
    & ", """ & strFolder & """;"
    CurrentDb.Execute strSQL
    
    Resume Exit_Handler
End Function
 Public Function TrailingSlash(varIn As Variant) As String
    If Len(varIn) > 0& Then
        If Right(varIn, 1&) = "\" Then
            TrailingSlash = varIn
        Else
            TrailingSlash = varIn & "\"
        End If
    End If
End Function
 
Hey, thanks for posting the working whole Squid. Appreciated!

And arnel makes a good point too. It makes sense to disallow the duplication at the table level.

Cheers,
 

Users who are viewing this thread

Back
Top Bottom