A split database architecture is best for developing, maintaining, and deploying Microsoft Access applications. The front-end database contains all the Access objects except the tables which reside in a separate back-end Access Jet database. The front-end database links to the tables in the back-end database, so it can be updated without worrying about changes to the data.
This is particularly important for multi-user applications where each user has a copy of the front-end database on their machine sharing the same centralized data. When the application is enhanced (new queries, forms, reports, code, etc.), it is simply distributed to each user. Programs like our Total Access Startup can centralize and automate the distribution process.
If you are not familiar with a split database architecture, read our paper on Splitting Microsoft Access Databases to Improve Performance and Simplify Maintainability
When a single database is converted to a split-database design, one sometimes sees significant performance degradation, especially over a network. Speed may vary with different portions of the application and number of users. Some people settle for this but there may be a simple way to significantly improve performance.
When a database is opened, Microsoft Access creates a lock file on disk. You may see these are *.LDB or *.LACCDB files. When the database is closed, the lock file is deleted.
This is not a big deal for a single MS Access database application which would create the lock file when the database is opened and maintain it until the database is closed. But in a linked database design, the lock file on the back-end database may be created and deleted every time a table is opened and closed. When no connections to any tables on the back end database remain open, the lock file is deleted. That takes time.
You can significantly improve the performance of your Access database by maintaining an open connection to the back-end database throughout the time your front-end database is opened.
By forcing Access to keep the linked table's database open, Access avoids creating a new lock on the backend database every time one of its tables is used. This lets you open tables, forms, and reports much faster. Over a network, you'll usually see a substantial improvement with how quickly a form opens when it's based on a linked table.
To create a persistent connection to the linked database, open a MS Access database variable in VBA using the DAO OpenDatabase method. Keep this variable open as long as your application is running.
The procedure below supports multiple backend databases. Edit the section with the list of databases to match your backend database(s):
Sub OpenAllDatabases(pfInit As Boolean) ' Open a handle to all databases and keep it open during the entire time the application runs. ' Params : pfInit TRUE to initialize (call when application starts) ' FALSE to close (call when application ends) ' Source : Total Visual SourceBook Dim x As Integer Dim strName As String Dim strMsg As String ' Maximum number of back end databases to link Const cintMaxDatabases As Integer = 2 ' List of databases kept in a static array so we can close them later Static dbsOpen() As DAO.Database If pfInit Then ReDim dbsOpen(1 To cintMaxDatabases) For x = 1 To cintMaxDatabases ' Specify your back end databases Select Case x Case 1: strName = "H:\folder\Backend1.mdb" Case 2: strName = "H:\folder\Backend2.mdb" End Select strMsg = "" On Error Resume Next Set dbsOpen(x) = OpenDatabase(strName) If Err.Number > 0 Then strMsg = "Trouble opening database: " & strName & vbCrLf & _ "Make sure the drive is available." & vbCrLf & _ "Error: " & Err.Description & " (" & Err.Number & ")" End If On Error GoTo 0 If strMsg <> "" Then MsgBox strMsg Exit For End If Next x Else On Error Resume Next For x = 1 To cintMaxDatabases dbsOpen(x).Close Next x End If End Sub
Call this when your application starts:
OpenAllDatabases True
When you finish, call this to close the database variables/handles:
OpenAllDatabases False
For instance, if you have a form that controls the application and remains open during the entire time the user is using your database, add the code to the OnOpen and OnClose events.
This simple technique yields considerable performance gains.
Good luck!
Strategic Overview
Microsoft Access within an Organization's Database Strategy
How many simultaneous Microsoft Access users?
Blaming Microsoft Access instead of the Developer
Microsoft Access Version Feature Differences
Microsoft Access Versions, Service Packs and Updates
Microsoft Office 365 Access Update Version Releases
Top 14 Features Added with MS Access 2007
Taking Over Legacy MS Access Databases
Winner of Every Best Access Add-in Award
Set AutoNumber Starting Number Other than 1
Avoid Unnecessary or Duplicate Indexes
Copy Command Button and Keep Picture
Module VBA to Forms and Controls
Subform Reference to Control Rather than Field
Suppress Page Headers and Footers on the First Page of Your Report
Annual Monthly Crosstab Columns
Add Buttons to the Quick Access Toolbar
Collapse the Office Ribbon for more space
Avoid Exits in the Body of a Procedure
Send Emails with DoCmd.SendObject
Error Handling and Debugging Techniques
Error Number and Description Reference
Remote Desktop Connection Setup
Terminal Services and RemoteApp Deployment
Missing Package & Deployment Wizard
Remove 'Save to SharePoint Site' Prompt from an Access Database
Class Not Registered Run-time Error -2147221164
Microsoft Access to SQL Server Upsizing Center
When and How to Upsize Access to SQL Server
SQL Server Express Versions and Downloads
Deploying MS Access Linked to SQL Azure
SQL Server Azure Usage and DTU Limits