See answers below:
Amy Blankenship said:
Hello, all;
I have been working on a DB for a client. They are based in another
state,
so I keep sending them the whole database to test. What I'd like to do
is
split the database so that I can continue to work on the FE and the
queries,
and they can get on with entering data in the tables, because the
production
date is getting closer & closer. But before I do this, I want to be
really
sure it will work. So I have some questions.
First, when I split the DB, which side will the queries land on?
Queries will be in the FE. Only tables will reside in the BE. All other
objects are in the FE.
Second, can I give the FE a relative path to the backend? (i.e.
".\backend.mdb") If so, where does this go?
No, you will need to use either a drive path, or preferably a UNC path
(server name and path). This is preferred because different users may
have
different drive mappings, so if User A has a server folder mapped as S:
and
User B has it mapped as F:, then if the links are specified as
S:\SomeFolder\MyDatabase.mdb, the User B will get an error.
Third, will it still be possible to run queries from outside the
database?
When you say "outside the database", I assume you mean outside the BE.
The
answer is yes.
"Exec [myquery] param1, param2"
If the queries wind up in the FE, will it be possible to move them back
to
the backend in the production DB? If so, how would I go about that?
They don't go there. All objects except tables go in the FE. From a
practical point of view, you would not know whether the table you are
referencing is a local table or a linked table.
The access help seems to be a bit thin on this sort of info. Or maybe
I'm a
bit thick...
It take a little getting used to. The trickiest part is managing the
links.
While you are doing your development, you will have the links establised
to
the location of your BE. Once you deliver that to the client, those links
are no longer valid. You will have to have a method to relink to the BE
for
each user. We will get back to that in a moment.
What I want to point out now is that the FE should NEVER be on a shared
folder or used by more than one user. It works, but there are a number of
issues - more than I have time to discuss at the moment. Just trust me on
this one. Each user should have his own copy of the FE on his computer.
(Fewer problems, runs faster, reduces network traffic).
Now the relink issue. The first time a user opens the FE and tries to
access
data in the BE after you deliver it, it will error because it can't find
the
tables. What you need to do in whatever code runs when you start up is to
test to see if the links are valid and If they are not, progammatically
relink. This gets a bit involved, because you will need to test each
table's
connection property. Here is some sample code that shows how to test for a
good connection:
On Error Resume Next
Set dbs = CurrentDb()
For intCount = dbs.TableDefs.Count - 1 To 0 Step -1 ' Look for a linked
table
Set tdf = dbs.TableDefs(intCount)
If tdf.Connect <> "" Then ' This is not a linked table
strConnect = dbs.TableDefs(dbs.TableDefs(0).NAME).Connect '
Find The Current Link
tdf.Connect = strConnect
tdf.RefreshLink ' Try to connect to it
If Err = 0 Then ' The link is still good, carry on
Exit For
Else
********
Then, I would suggest using a common dialog box to allow the user to
select
the BE (This will require a little user training)
Now, as to relinking:
Here is a function that performs the relink (strNewPath is the full path
and
name of the BE database:
Private Function ReLink(strNewPath As String) As Boolean
Dim dbs As Database
Dim tdf As TableDef
Dim intCount As Integer
Dim frmCurrentForm As Form
DoCmd.Hourglass True
On Error GoTo ErrLinkUpExit
Me.lblMsg.Visible = True
Me.cmdOK.Enabled = False
Set dbs = CurrentDb
For intCount = 0 To dbs.TableDefs.Count - 1
Set tdf = dbs.TableDefs(intCount)
If tdf.Connect <> "" Then
Me.lblMsg.Caption = "Refreshing " & tdf.NAME
DoEvents
tdf.Connect = ";DATABASE=" & strNewPath
tdf.RefreshLink
End If ' tdf.Connect <> ""
Next intCount
Set dbs = Nothing
Set tdf = Nothing
DoCmd.Hourglass False
Me.lblMsg.Caption = "All Links were refreshed!"
ReLink = True
Me.cmdOK.Enabled = True
Exit Function
ErrLinkUpExit:
DoCmd.Hourglass False
Select Case Err
Case 3031 ' Password Protected
Me.lblMsg.Caption = "Back End '" & strNewPath & "'" & " is
password protected"
Case 3011 ' Table missing
DoCmd.Hourglass False
Me.lblMsg.Caption = "Back End does not contain required table
'"
& tdf.SourceTableName & "'"
Case 3024 ' Back End not found
Me.lblMsg.Caption = "Back End Database '" & strNewPath & "'" &
"
Not Found"
Case 3051 ' Access Denied
Me.lblMsg.Caption = "Access to '" & strNewPath & "' Denied" &
vbCrLf & _
"May be Network Security or Read Only Database"
Case 3027 ' Read Only
Me.lblMsg.Caption = "Back End '" & strNewPath & "'" & " is Read
Only"
Case 3044 ' Invalid Path
Me.lblMsg.Caption = strNewPath & " Is Not a Valid Path"
Case 3265
Me.lblMsg.Caption = "Table '" & tdf.NAME & "'" & _
" Not Found in ' " & strNewPath & "'"
Case 3321 ' Nothing Entered
Me.lblMsg.Caption = "No Database Name Entered"
Case Else
Me.lblMsg.Caption = "Uncaptured Error " & str(Err) &
Err.DESCRIPTION
End Select
Set tdf = Nothing
ReLink = False
End Function
*************
Obviously, you will need to adapt this to your application. Post back if
you have questions.