Ms-Access Advanced VBA Programming Techniques, Tips and Tricks.

Lost Links of External Tables

We have already learned several methods to work with external data sources. By linking them to MS-Access Database or directly opening them in Queries by setting SourceDatabase and SourceConnectStr Properties. In either case the Source Data must be present in their original location all the time.

But, there is a possibility that the links to some of these tables can be lost either by deleting or renaming the source table by mistake. We will come to know about the error only when we attempt to work with the external tables and chances are that the error pops up in the middle of some process steps.

To alleviate this problem run a check on the linked tables as soon as the Database is open for normal operations. If any of the linked Tables is not in place then warn the User about it and shut down the Application if it has serious implications.

How do we determine whether a linked external table has lost its connection with the Database or not? It is easy, attempt to open the linked table and if it runs into error you can be sure that either it got deleted or name changed.

There may be several tables in a database, local as well as linked ones. How can we single out the linked ones alone and open them to check the status? Again this is not a big issue and you already have the answer if you have gone through the earlier Articles explaining several methods of accessing external data and usage of Connection Properties of Linked Tables and Queries.

We need a small VBA routine to iterate through the Table definitions and check the Connect Property value and if it is set with a Connect String then it is a linked table otherwise it is a local table. When we encounter a linked table we will attempt to open it to read data. If this process triggers an Error then we will prepare a list of such cases and display it at the end, to inform the User so that she can initiate appropriate remedial action to rectify the error.

A sample VBA routine is given below. Copy and paste the program in a Global Module and save it.

Public Function LostLinks()
'----------------------------------------------------
'Author : a.p.r. pillai
'URL    : www.msaccesstips.com
'Date   : 21/09/2008
'----------------------------------------------------
Dim msg As String, tbldef As TableDef
Dim strConnect As String, cdb As Database
Dim rst As Recordset, strTableName As String
Dim strDatabase As String, loc As Integer
Dim loc2 As Integer

On Error Resume Next

Set cdb = CurrentDb
For Each tbldef In cdb.TableDefs
    strConnect = tbldef.Connect

    If Len(strConnect) > 0 Then
       strTableName = tbldef.NAME
       Set rst = cdb.OpenRecordset(strTableName, dbOpenDynaset)
       If Err > 0 Then
          If Len(msg) = 0 Then
             msg = "The following Linked Tables are missing:" & vbCr & vbCr
          End If
          msg = msg & strTableName & vbCr
          Err.Clear
        End If
        rst.Close
    End If
Next

If Len(msg) > 0 Then
    MsgBox msg, , "LostLinks()"
End If

End Function

Call the Routine from an Autoexec Macro or from Form_Load() Event Procedure of the Application's Startup or Main Screen.

Share:

No comments:

Post a Comment

Trending

Popular Posts

Search This Blog

Blog Archive

Powered by Blogger.

Labels

Forms How Tos MS-Access Security Functions Reports Animations msaccess animation msaccess forms Utilities msaccess controls Access and Internet MS-Access Scurity MS-Access and Internet Queries External Links msaccess reports msaccess tips Menus and Toolbars Accesstips MsaccessLinks Process Controls Art Work Downloads msaccess How Tos Graph Charts msaccessQuery List Boxes Command Buttons Emails and Alerts Query Combo Boxes Custom Wizards msaccess graphs msaccess reporttricks ms-access functions msaccessprocess security advanced Access Security DOS Commands Data Macros Menus Property Report Top Values VBA msaccess email msaccess menus progressmeter Access2007 Array Auto-Number Command Button Join Microsoft Numbering System Records Security Split SubForm Table Utility Workgroup database msaccess functions msaccess wizards Access2003 Accounting Year Action Animation Attachment Binary Numbers Budgeting Calculation ChDir Color Palette Conditional Formatting Controls Copy Custom Functions Data Filtering Data Type Defining Pages Diagram Disk Dynamic Lookup Error Handler Excel Export Expression External Field Type Fields Filter Form Form Instances Formatting Groups Hexadecimal Numbers Import Labels List Logo Macro Mail Merge Main Form Memo Methods Monitoring Object Reference Objects Octal Numbers Operating System Paste Primary-Key Product Rank Reading Rich Text Sequence SetFocus Summary Tab-Page Time Difference Union Query User Users Variables Water-Mark Word automatically commands function hyperlinks iSeries Date iif ms-access msaccess msaccess alerts pdf files reference restore switch text toolbar tutorial updating upload vba code

Featured Post

Important Notice

Dear Readers, Very sorry to inform you that I am finding it difficult to renew my contract with the Hostgator Hosting Plans to continue prov...

Labels

Blog Archive

Recent Posts