Results 1 to 6 of 6
  1. #1
    Join Date
    Feb 2019
    Posts
    1,103

    Need VBA routines that merges all (structure identical) tables into single table.

    Hello:

    I need to develop a VBA routine/function that merges n tables (w/ same field structure) into a single table named [T000_MergedData].



    Additional information:
    - VBA routine needs to scan through DB's TDF and apply merge routine to *only* those tables having table name prefix = "T100_".
    - This sample DB includes five (5) tables where 2 tables ("T010_IgnoreInMerge" and "Table1_IgnoreInMerge") do NOT meet the prefix criteria. So, they must be ignored in the merge routine.
    - To ensure record count won't be inflated, [T000_MergedData]'s record set must be deleted prior to each execution.
    - If VBA runs successful, [T000_MergedData] should contain only 35 records (15 from "T100_Org1_IncludeInMerge" and 20 from "T100_Org2_IncludeInMerge") after each execution.
    - Naturally, the record count from any new/additional tables starting with "T100" would need to be added to the total count.

    My question:
    - What does such VBA routine/loop would look like that, theoretically, merges records from dozens or hundreds of T100_ tables into single table [T000_MergedData]?
    Attached Files Attached Files

  2. #2
    June7's Avatar
    June7 is offline VIP
    Windows 10 Access 2010 32bit
    Join Date
    May 2011
    Location
    The Great Land
    Posts
    53,771
    UNION query has a limit of 50 SELECT lines so not feasible with hundreds of T100_ tables.

    Have a structure that loops through tables collection (this is a common topic) and looks for "T100" prefix in table name. If match, run INSERT SELECT action SQL.

    Begin procedure with DELETE action SQL.

    Why don't you make an effort to write code and let us know how it goes.
    How to attach file: http://www.accessforums.net/showthread.php?t=70301 To provide db: copy, remove confidential data, run compact & repair, zip w/Windows Compression.

  3. #3
    Join Date
    Feb 2019
    Posts
    1,103
    The VBA code below only executes the query one (1) time. It does NOT replace the table reference in the FROM statement with any subsequent table in the TDF scan.

    See attached updated sample DB with VBA (in form 'F01_MainMenu').

    Please advise as to how the VBA needs to be modified so that all tables meeting the T100 criteria will have records appended as part of the loop.

    Code:
    Option Compare Database
    
    
    Private Sub cmdMergeTables_Click()
        
        'Error handling
        On Error GoTo Err_PrematureClose_Click
        
        'Declare variables
        Dim tdf As DAO.TableDef
        Dim sTable As String
        Dim strSQL As String
        
        'Clear the table
        CurrentDb.Execute "DELETE * FROM T000_MergedData;", dbFailOnError
        
        'Get the database and associated query
        Set db = CurrentDb()
        Set qdf = db.QueryDefs("Q_MergeData")
            
        'Start looping through the table definitions
        For Each tdf In CurrentDb.TableDefs
            sTable = tdf.Name
                    
                If Left(sTable, 5) <> "T100_" Then GoTo NEXT_TDF
                                        
                'I need to auto-replace table reference in 'FROM T100_Org1_IncludeInMerge' with TDF table name
                strSQL = "INSERT INTO T000_MergedData ( ORGANIZATION, [MODULE], SOURCE_FIELD, TARGET_FIELD ) " & _
                         "SELECT ORGANIZATION, MODULE, SOURCE_FIELD, TARGET_FIELD " & _
                         "FROM " & sTable & ";"
               
        'Apply the new SQL statement to specified query
        qdf.SQL = strSQL
    
    
        'Open query
        DoCmd.OpenQuery "Q_MergeData", acViewNormal, acReadOnly
        
        'Empty memory
        Set db = Nothing
        Set qdf = Nothing
                        
    NEXT_TDF:
        Next tdf
        
        MsgBox "All done! The T000_MergedData table has been refreshed.", vbInformation, "T000_MergedData Refresh Completed"
               
    'Begin error handling
    Exit_PrematureClose_Click:
        Exit Sub
        
    Err_PrematureClose_Click:
        Resume Exit_PrematureClose_Click
               
    End Sub
    Attached Files Attached Files

  4. #4
    orange's Avatar
    orange is offline Moderator
    Windows 10 Office 365
    Join Date
    Sep 2009
    Location
    Ottawa, Ontario, Canada; West Palm Beach FL
    Posts
    16,870
    Where are the T100_*** tables located? How many in total? What is the key difference in these T100_** tables?
    I haven't looked at your zip.

  5. #5
    moke123's Avatar
    moke123 is offline Me.Dirty=True
    Windows 11 Office 365
    Join Date
    Oct 2012
    Location
    Ma.
    Posts
    1,879
    This works for me.
    Any reason you need a qrydef?


    Code:
    Dim db As DAO.Database
        Dim tdf As DAO.TableDef
        Dim strSQL As String
        
        Set db = CurrentDb
        
        db.Execute "DELETE * FROM T000_MergedData;", dbFailOnError
    
    
        For Each tdf In db.TableDefs
    
    
            If Left(tdf.Name, 5) = "T100_" Then
                
                strSQL = "INSERT INTO T000_MergedData ( ORGANIZATION, [MODULE], SOURCE_FIELD, TARGET_FIELD ) " & _
                    "SELECT ORGANIZATION, MODULE, SOURCE_FIELD, TARGET_FIELD " & _
                    "FROM " & tdf.Name & ";"
                         
                ' Debug.Print strSQL
                         
                db.Execute strSQL, dbFailOnError
                
            End If
    
    
        Next
    If this helped, please click the star * at the bottom left and add to my reputation- Thanks

  6. #6
    Join Date
    Feb 2019
    Posts
    1,103
    moke123 -- PERFECT!! That works great. I added several new tables including different tables names following the T_100 prefix.

    Record count is 100% accurate... many thanks!

    //

    orange -- thanks for chiming in... tables were/are included in the zip file. VBA routine has been solved. Cheers.

Please reply to this thread with any new information or opinions.

Similar Threads

  1. Replies: 16
    Last Post: 02-09-2017, 03:48 PM
  2. Replies: 3
    Last Post: 07-24-2015, 06:39 AM
  3. Replies: 14
    Last Post: 09-09-2014, 01:30 PM
  4. 500 Tables Join as Single Table
    By Franklin in forum Access
    Replies: 2
    Last Post: 08-31-2012, 01:11 PM
  5. Show two tables in single table
    By access in forum Forms
    Replies: 8
    Last Post: 06-11-2009, 11:57 AM

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •  
Other Forums: Microsoft Office Forums