IN THE SPOTLIGHT: MDE to MDB Conversion Service
(also supports: ACCDE to ACCDB, ADE to ADP, etc)
IN THE SPOTLIGHT: Access Database Repair Service
An in-depth repair service for corrupt Microsoft Access files
IN THE SPOTLIGHT: vbWatchdog
VBA error handling just got easier...
" vbWatchdog is off the chart. It solves a long standing problem of how to consolidate error handling into one global location and avoid repetitious code within applications. "
- Joe Anderson,
Microsoft Access MVP
Meet Shady, the vbWatchdog mascot watching over your VBA code →
(courtesy of Crystal Long, Microsoft Access MVP)
IN THE SPOTLIGHT: vbMAPI
An Outlook / MAPI code library for VBA, .NET and C# projects
Get emails out to your customers reliably, and without hassle, every single time.
Use vbMAPI alongside Microsoft Outlook to add professional emailing capabilities to your projects.
IN THE SPOTLIGHT: Code Protector
Standard compilation to MDE/ACCDE format is flawed and reversible.
Is there a possibility to REALLY protect Access data in an backend database file with an Access 2003 runtime app? At present I do not want to switch to Access 2007 as many of my customers are still working with Windows 2000. Is there a chance to use an Access 2007 database file as backend (which seems to be secure with the new database password) with an Access 2003 frontend ? Thanks for helping H. Peter LienhardtAs we all know, Access 2003 uses a single encryption method, which also happens to be very weak. Unfortunately it's hard coded unlike Access 2007 which uses the much improved CryptoAPI.
Is there a chance to use an Access 2007 database file as backend (which seems to be secure with the new database password) with an Access 2003 frontend?
1. You can't use direct link tables from an Access 2003 file to an Access 2007 backend.
2. You can't use ODBC link tables from an Access 2003 file to an Access 2007 backend.
Option Explicit ' Code: ModLateBindingForms ' Desc: Simple helper module for binding forms to ADO recordsets, using a global backend connection ' Code by (c) Wayne Phillips, 26/06/2008 ' This code is provided for free from www.everythingaccess.com ' Please leave the copyright notice in place - Thank you. ' REQUIREMENTS: Access 2000 / 2002 / 2003 ' VBA Reference to the Microsoft ActiveX Data Objects Library Public g_ADOBackEndConn As ADODB.Connection Public Const g_BackendPath = "C:\Northwind2007.accdb" Public Const g_BackendPassword = "" ' For Microsoft.ACE.OLEDB.12.0,you need Microsoft Office 12.0 Access Database Engine to be installed. Private Const g_BackendADOProvider = "Microsoft.ACE.OLEDB.12.0" Private Const g_BackEndADOConnectStr = "Provider=" & g_BackendADOProvider & ";" & _ "Data Source=" & g_BackendPath & ";" & _ "Jet OLEDB:Database Password=" & g_BackendPassword Public Sub LateBindFormToBackendRecordset(Frm As Object, strSQL As String, _ Optional LockType As LockTypeEnum = adLockOptimistic, _ Optional CursorType As CursorTypeEnum = adOpenKeyset) On Error GoTo ErrorHandler Dim FormRecordset As ADODB.Recordset If EnsureBackendIsConnected() = True Then Set FormRecordset = New ADODB.Recordset With FormRecordset Set .ActiveConnection = g_ADOBackEndConn .Source = strSQL .LockType = LockType .CursorType = CursorType .Open ' If this fails, error handler will kick in End With Set Frm.Recordset = FormRecordset Else MsgBox "LateBindFormToBackendRecordset error: ADO backend connection failed" End If Exit Sub ErrorHandler: Set FormRecordset = Nothing ' not strictly needed MsgBox "Error occured in procedure 'LateBindFormToBackendRecordset'" & vbCrLf & vbCrLf & _ "Error Number: " & Err.Number & vbCrLf & _ "Description: " & Err.Description End Sub Public Function EnsureBackendIsConnected() As Boolean On Error GoTo ErrorHandler If g_ADOBackEndConn Is Nothing Then Set g_ADOBackEndConn = New ADODB.Connection g_ADOBackEndConn.Open g_BackEndADOConnectStr End If EnsureBackendIsConnected = True Exit Function ErrorHandler: Set g_ADOBackEndConn = Nothing MsgBox "Error occured in procedure 'EnsureBackendIsConnected'" & vbCrLf & vbCrLf & _ "Error Number: " & Err.Number & vbCrLf & _ "Description: " & Err.Description End Function
Private Sub Form_Open(Cancel As Integer) Call LateBindFormToBackendRecordset(Me, "SELECT TOP 5 * FROM Invoices") End Sub
How to
bind Microsoft Access forms to ADO recordsets (Microsoft KB Article)
Changing the encryption type in Access 2007
Access 12 Redistributable Database Engine Download
Wayne Phillips
www.everythingaccess.com
Rate this article:
iTech Masters | VAT: GB202994606 | Terms | Sitemap | Newsletter