Microsoft Edge Try Microsoft Edge A fast and secure browser that's designed for Windows 10 Get started

Skip to main content
Microsoft
Microsoft Support
  • Office
  • Windows
  • Surface
  • Xbox
  • Deals
  • Support
      • Windows apps
      • OneDrive
      • Outlook
      • Skype
      • OneNote
      • PCs & tablets
      • Accessories
      • VR & mixed reality
      • Microsoft HoloLens
      • Xbox games
      • PC games
      • Windows digital games
      • Movies & TV
      • Books
      • Microsoft Azure
      • Microsoft Dynamics 365
      • Microsoft 365
      • Cloud platform
      • Enterprise
      • Data platform
      • .NET
      • Visual Studio
      • Windows Dev Center
      • Docs
      • Microsoft Store
      • Free downloads & security
      • Education
      • Store locations
      • Gift cards
    • View all
    0
    Sign in
    Microsoft Support

    How to refresh links in a runtime application in Microsoft Access

    Content provided by Microsoft

    Content provided by Microsoft


    Summary


    In a run-time application, the front-end and back-end databases must be stored in the same folder. Even though you can change the default installation path of the back-end database to, for example, $AppPath\Folder1, there is no way for Access to refresh the links in the front-end to match the new installation location.

    One way to work around this behavior is to programmatically refresh the links by using ActiveX Extensibility Objects (ADOX) after the run-time application has been installed. The following is an illustration of how to implement this technique. Please note that this article assumes that the back-end databases are stored in subfolders under the front-end database.

    More Information


    1. Make sure you have the latest version of the Microsoft Data Access Components (MDAC) installed on your computer. MDAC can be found at the following Microsoft Web site:
      http://msdn.microsoft.com/en-us/data/aa937729.aspx
    2. Set a reference to Microsoft ADO Ext 2.5 (or later) for DDL and Security.
    3. Create a new database and name it FrontEnd.mdb.
    4. Import the Customers and Employees forms from the sample database Northwind.mdb into FrontEnd.mdb.
    5. Create a new database and subfolder under the folder where the FrontEnd.mdb file is located, for example, Folder1\Backend1.mdb.
    6. Import the Customer table from Northwind.mdb into Backend1.mdb.
    7. Create a new database and subfolder under the folder where the FrontEnd.mdb file is located, for example, Folder2\Backend2.mdb.
    8. Import the Employee table from Northwind.mdb into Backend2.mdb.
    9. Open the FrontEnd.mdb database and create a new module. In the module, paste in the following code:
      Option Compare Database
      Option Explicit

      Private Declare Function apiSearchTreeForFile Lib "ImageHlp.dll" Alias _
      "SearchTreeForFile" (ByVal lpRoot As String, ByVal lpInPath _
      As String, ByVal lpOutPath As String) As Long


      Function RefreshLinks()
      On Error GoTo ErrorHandler


      Dim objCat As New ADOX.Catalog 'Define the ADOX Catalog Object
      Dim objTbl As ADOX.Table 'Define the ADOX Table Object

      Dim strSearchFolder As String 'Folder to Search in.
      Dim strFilename As String 'Db Name of the Linked Table
      Dim strFullName As String 'Path & DB Name of the Linked Table.
      Dim strSearchFile As String 'The new path of the database.

      Dim blnTablesNotLinked As Boolean 'Determines if links are valid

      'Open the catalog
      objCat.ActiveConnection = CurrentProject.Connection

      'Loop through the table collection and refresh the linked tables.
      For Each objTbl In objCat.Tables

      ' Check to make sure the table is a linked table.
      If objTbl.Type = "LINK" Then
      strFullName = objTbl.Properties("Jet OLEDB:Link Datasource")
      strFilename = Mid(strFullName, InStrRev(strFullName, "\", _
      Len(strFullName)) + 1, Len(strFullName))
      strSearchFolder = CurrentProject.Path
      'The following line of code attempts to refresh the link.
      'If the source cannot be found an error is generated.
      'Please note that this code only checks one table to determine
      'whether or not the links are valid.
      objTbl.Properties("Jet OLEDB:Link Datasource") = strFullName

      If blnTablesNotLinked = False Then
      Exit Function
      Else
      'Set the search path to the path of the current project.
      'The assumption is that the linked tables are located in subfolders.
      strSearchFile = SearchFile(strFilename, strSearchFolder)
      objTbl.Properties("Jet OLEDB:Link Datasource") = strSearchFile
      End If
      End If
      Next

      MsgBox "The links were successfully refreshed!!! "

      ExitHandler:
      Exit Function

      ErrorHandler:
      Select Case Err.Number
      Case -2147467259
      blnTablesNotLinked = True
      Resume Next
      Case Else
      MsgBox Err.Description & " " & Err.Number
      Resume ExitHandler
      End Select
      End Function

      Function SearchFile(ByVal strFilename As String, _
      ByVal strSearchPath As String) As String
      'Search the folder for first occurrence of the source databases.
      Dim strBuffer As String
      Dim lngResult As Long
      SearchFile = ""
      strBuffer = String$(1024, 0)
      lngResult = apiSearchTreeForFile(strSearchPath, strFilename, strBuffer)
      If lngResult <> 0 Then
      If InStr(strBuffer, vbNullChar) > 0 Then
      SearchFile = Left$(strBuffer, InStr(strBuffer, vbNullChar) - 1)
      End If
      End If
      End Function
      This function checks the first linked table in the database to determine if the links are valid. If the links are not valid, the function searches for the database and refreshes the links.
    10. Create a new macro with the following properties, and name it AutoExec:

      Action: RunCode
      Function Name: RefreshLinks()

      Action: OpenForm
      Form Name: Customers

      Action: OpenForm
      Form Name: Employees
      Note that you can also call this function in the Open event of a hidden Startup Form.
    11. Build the package for the run-time application. Remember to add "Folder1" and "Folder2" to the respective installation locations.

      For Access 2007 and for Access 2003, add the back-end files in the "Additional Files" section, and then provide respective folder names "Folder1" and "Folder2" in the Install Subfolder column.

      For Access 2002 and for Access 2000, add "$(AppPath)\Folder1\" and "$(AppPath)\Folder2\" to the respective installation locations on the Install Location page.

    12. Deploy the run-time application.
    When the application starts, an hourglass indicates that the links are being refreshed. The Customers and Employees forms will then open with valid data.

    References


    For more information about how to refresh linked tables, click the following article number to view the article in the Microsoft Knowledge Base:

    209862 How to relink back-end tables with the common dialog control in Access 2000


    Last Updated: Oct 30, 2008
    • Email
    • Print
    Thanks! Your feedback will help us improve the support experience.

    Support

    Support

    • Find downloads
    • Account support
    • Supported products list
    • Microsoft Lifecycle Policy

    Security

    Security

    • Safety & Security Center
    • Download Security Essentials
    • Malicious Software Removal Tool

    Contact us

    Contact us

    • Report a support scam
    • Contact Microsoft Support
    • Locate Microsoft addresses worldwide
    This site in other countries/regions
    Algérie - Français
    Argentina - Español
    Australia - English
    Belgique - Français
    België - Nederlands
    Bolivia - Español
    Bosna i Hercegovina - Hrvatski
    Brasil - Português
    Canada - English
    Canada - Français
    Chile - Español
    Colombia - Español
    Costa Rica - Español
    Crna Gora - Srpski
    Danmark - Dansk
    Deutschland - Deutsch
    Dominican Republic - Español
    Ecuador - Español
    Eesti - Eesti
    El Salvador - Español
    España - Español
    Estados Unidos - Español
    France - Français
    Guatemala - Español
    Hong Kong SAR - English
    Hrvatska - Hrvatski
    India - English
    Indonesia (Bahasa) - Bahasa
    Ireland - English
    Italia - Italiano
    Latvija - Latviešu
    Lietuva - Lietuvių
    Luxembourg - Français
    Magyarország - Magyar
    Malaysia - English
    Maroc - Français
    México - Español
    Nederland - Nederlands
    New Zealand - English
    Norge - Bokmål
    Panamá - Español
    Paraguay - Español
    Perú - Español
    Philippines - English
    Polska - Polski
    Portugal - Português
    Puerto Rico - Español
    România - Română
    Schweiz - Deutsch
    Singapore - English
    Slovenija - Slovenščina
    Slovensko - Slovenčina
    South Africa - English
    Srbija - Srpski
    Suisse - Français
    Suomi - Suomi
    Sverige - Svenska
    Tunisie - Français
    Türkiye - Türkçe
    United Kingdom - English
    United States - English
    Uruguay - Español
    Venezuela - Español
    Việt Nam - Tiếng việt
    Ísland - Íslenska
    Österreich - Deutsch
    Česká Republika - Čeština
    Ελλάδα - Ελληνικά
    България - Български
    Казахстан - Русский
    Россия - Русский
    Україна - Українська
    ישראל - עברית
    الإمارات العربية المتحدة - العربية
    المملكة العربية السعودية - العربية
    مصر - العربية
    भारत - हिंदी
    ไทย - ไทย
    中国 - 简体中文
    台灣 - 繁體中文
    日本 - 日本語
    香港特別行政區 - 繁體中文
    대한민국 - 한국어
    English (United States)
    • Terms of use
    • Privacy & cookies
    • Trademarks
    • © Microsoft 2018