Results 1 to 3 of 3
  1. #1
    jimrosser is offline Novice
    Windows 11 Access 2019
    Join Date
    Jan 2023
    Posts
    11

    Excel VBA store table names as strings

    Hi - I'm trying to create a dropdown box in Excel based on table names in Access db.


    Below is the code I'm using to get the data I foresee maybe 15 tables. But am unsure how to store the data as a variable in VBA.

    Code:
    Sub Example1()'an Access object
    Dim objAccess As Object
    'connection string to access database
    Dim strConnection As String
    'catalog object
    Dim objCatalog As Object
    'connection object
    Dim cnn As Object
    Dim i As Integer
    Dim intRow As Integer
    
    Set objAccess = CreateObject("Access.Application")
    'open access database
    Call objAccess.OpenCurrentDatabase( _
    "D:StuffBusinessTempNewDB.accdb")
    'get the connection string
    strConnection = objAccess.CurrentProject.Connection.ConnectionString
    'close the access project
    objAccess.Quit
    'create a connection object
    Set cnn = CreateObject("ADODB.Connection")
    'assign the connnection string to the connection object
    cnn.ConnectionString = strConnection
    'open the adodb connection object
    cnn.Open
    'create a catalog object
    Set objCatalog = CreateObject("ADOX.catalog")
    'connect catalog object to database
    objCatalog.ActiveConnection = cnn
    'loop through the tables in the catalog object
    intRow = 1
    For i = 0 To objCatalog.Tables.Count - 1
        'check if the table is a user defined table
        If objCatalog.Tables.Item(i).Type = "TABLE" Then
            'get the tables name
            Cells(intRow, 1) = objCatalog.Tables.Item(i).Name
            intRow = intRow + 1
        End If
    Next i
    End Sub

  2. #2
    pbaldy's Avatar
    pbaldy is offline Who is John Galt?
    Windows XP Access 2007
    Join Date
    Feb 2010
    Location
    Nevada, USA
    Posts
    22,518
    How about

    VariableName = VariableName & objCatalog.Tables.Item(i).Name & ","

    You can trim off the trailing comma after the loop if you want:

    VariableName = Left(VariableName, Len(VariableName) - 1)
    Paul (wino moderator)
    MS Access MVP 2007-2019
    www.BaldyWeb.com

  3. #3
    June7's Avatar
    June7 is online now VIP
    Windows 10 Access 2010 32bit
    Join Date
    May 2011
    Location
    The Great Land
    Posts
    52,822
    I tested your code. Here is the list it returned:
    ~TMPCLP651611
    Colors
    Holidays
    Labels
    Orders
    pedInfo
    TreeNodes
    USysApplicationLog
    USysRibbons

    No linked tables were included. Here is info about the TMPCLP item https://www.access-programmers.co.uk...-table.293579/
    Compact & Repair did remove the item.

    Consider a query like:

    SELECT MSysObjects.*
    FROM MSysObjects
    WHERE (Type=4 Or Type=5) AND (Flags=0 Or Flags=537919488);

    Returns tables (local and linked) and queries but not Sys tables. If you use prefixes for object names, such as "qry", can add filter to exclude.

    Rats, Excel does not have read permission for MSysObjects. Kills that idea.

    However, can use DAO TableDefs to return local and linked tables. Have to set VBA reference to Microsoft DAO x.x Object Library.
    Code:
    Dim ws As DAO.Workspace
    Dim db As DAO.Database
    Dim tdfLoop As DAO.TableDef
    Set ws = DBEngine.Workspaces(0)
    Set db = ws.OpenDatabase("C:\Users\Owner\June\LL\Umpires.accdb")
    With db
        Debug.Print .TableDefs.Count & " TableDefs in " & .Name
        For Each tdfLoop In .TableDefs
            If Not tdfLoop.Name Like "*Sys*" Then Debug.Print "    " & tdfLoop.Name
        Next tdfLoop
    End With
    Last edited by June7; 01-16-2023 at 11:51 PM.
    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.

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

Similar Threads

  1. Replies: 7
    Last Post: 03-21-2018, 04:58 AM
  2. Replies: 2
    Last Post: 02-03-2018, 06:54 PM
  3. Replies: 11
    Last Post: 03-02-2016, 11:01 AM
  4. Store data in Excel automatically is that possible
    By drumaster in forum Import/Export Data
    Replies: 2
    Last Post: 04-27-2011, 03:28 PM
  5. Proper way to store Names
    By trb5016 in forum Database Design
    Replies: 5
    Last Post: 08-22-2010, 10:16 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